-<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.193 2008/11/04 22:40:40 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.194 2008/11/09 00:28:34 tgl Exp $ -->
<chapter Id="runtime-config">
<title>Server Configuration</title>
</listitem>
</varlistentry>
+ <varlistentry id="guc-intervalstyle" xreflabel="IntervalStyle">
+ <term><varname>IntervalStyle</varname> (<type>string</type>)</term>
+ <indexterm>
+ <primary><varname>IntervalStyle</> configuration parameter</primary>
+ </indexterm>
+ <listitem>
+ <para>
+ Sets the display format for interval values.
+ The value <literal>sql_standard</> will produce
+ output matching <acronym>SQL</acronym> standard interval literals.
+ The value <literal>postgres</> (which is the default) will produce
+ output matching <productname>PostgreSQL</> releases prior to 8.4
+ when the <xref linkend="guc-datestyle">
+ parameter was set to <literal>ISO</>.
+ The value <literal>postgres_verbose</> will produce output
+ matching <productname>PostgreSQL</> releases prior to 8.4
+ when the <varname>DateStyle</>
+ parameter was set to non-<literal>ISO</> output.
+ </para>
+ <para>
+ The <varname>IntervalStyle</> parameter also affects the
+ interpretation of ambiguous interval input. See
+ <xref linkend="datatype-interval-input"> for more information.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry id="guc-timezone" xreflabel="timezone">
<term><varname>timezone</varname> (<type>string</type>)</term>
<indexterm>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.231 2008/11/03 22:14:40 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.232 2008/11/09 00:28:34 tgl Exp $ -->
<chapter id="datatype">
<title id="datatype-title">Data Types</title>
<entry>294276 AD</entry>
<entry>1 microsecond / 14 digits</entry>
</row>
- <row>
- <entry><type>interval [ <replaceable>fields</replaceable> ] [ (<replaceable>p</replaceable>) ]</type></entry>
- <entry>12 bytes</entry>
- <entry>time intervals</entry>
- <entry>-178000000 years</entry>
- <entry>178000000 years</entry>
- <entry>1 microsecond / 14 digits</entry>
- </row>
<row>
<entry><type>date</type></entry>
<entry>4 bytes</entry>
<entry>24:00:00-1459</entry>
<entry>1 microsecond / 14 digits</entry>
</row>
+ <row>
+ <entry><type>interval [ <replaceable>fields</replaceable> ] [ (<replaceable>p</replaceable>) ]</type></entry>
+ <entry>12 bytes</entry>
+ <entry>time intervals</entry>
+ <entry>-178000000 years</entry>
+ <entry>178000000 years</entry>
+ <entry>1 microsecond / 14 digits</entry>
+ </row>
</tbody>
</tgroup>
</table>
</para>
</sect3>
- <sect3>
- <title>Intervals</title>
-
- <indexterm>
- <primary>interval</primary>
- </indexterm>
-
- <para>
- <type>interval</type> values can be written with the following syntax:
-
-<programlisting>
-<optional>@</> <replaceable>quantity</> <replaceable>unit</> <optional><replaceable>quantity</> <replaceable>unit</>...</> <optional><replaceable>direction</></optional>
-</programlisting>
-
- Where: <replaceable>quantity</> is a number (possibly signed);
- <replaceable>unit</> is <literal>microsecond</literal>,
- <literal>millisecond</literal>, <literal>second</literal>,
- <literal>minute</literal>, <literal>hour</literal>, <literal>day</literal>,
- <literal>week</literal>, <literal>month</literal>, <literal>year</literal>,
- <literal>decade</literal>, <literal>century</literal>, <literal>millennium</literal>,
- or abbreviations or plurals of these units;
- <replaceable>direction</> can be <literal>ago</literal> or
- empty. The at sign (<literal>@</>) is optional noise. The amounts
- of different units are implicitly added up with appropriate
- sign accounting. <literal>ago</literal> negates all the fields.
- </para>
-
- <para>
- Quantities of days, hours, minutes, and seconds can be specified without
- explicit unit markings. For example, <literal>'1 12:59:10'</> is read
- the same as <literal>'1 day 12 hours 59 min 10 sec'</>. Also,
- a combination of years and months can be specified with a dash;
- for example <literal>'200-10'</> is read the same as <literal>'200 years
- 10 months'</>. (These shorter forms are in fact the only ones allowed
- by the SQL standard.)
- </para>
-
- <para>
- When writing an interval constant with a <replaceable>fields</>
- specification, or when assigning to an interval column that was defined
- with a <replaceable>fields</> specification, the interpretation of
- unmarked quantities depends on the <replaceable>fields</>. For
- example <literal>INTERVAL '1' YEAR</> is read as 1 year, whereas
- <literal>INTERVAL '1'</> means 1 second.
- </para>
-
- <para>
- Internally <type>interval</> values are stored as months, days,
- and seconds. This is done because the number of days in a month
- varies, and a day can have 23 or 25 hours if a daylight savings
- time adjustment is involved. Because intervals are usually created
- from constant strings or <type>timestamp</> subtraction, this
- storage method works well in most cases. Functions
- <function>justify_days</> and <function>justify_hours</> are
- available for adjusting days and hours that overflow their normal
- periods.
- </para>
- </sect3>
-
<sect3>
<title>Special Values</title>
</tgroup>
</table>
- <para>
- <type>interval</type> output looks like the input format, except
- that units like <literal>century</literal> or
- <literal>week</literal> are converted to years and days and
- <literal>ago</literal> is converted to an appropriate sign. In
- ISO mode the output looks like:
-
-<programlisting>
-<optional> <replaceable>quantity</> <replaceable>unit</> <optional> ... </> </> <optional> <replaceable>days</> </> <optional> <replaceable>hours</>:<replaceable>minutes</>:<replaceable>seconds</> </optional>
-</programlisting>
- </para>
-
<para>
The date/time styles can be selected by the user using the
<command>SET datestyle</command> command, the <xref
<envar>PGDATESTYLE</envar> environment variable on the server or
client. The formatting function <function>to_char</function>
(see <xref linkend="functions-formatting">) is also available as
- a more flexible way to format the date/time output.
+ a more flexible way to format date/time output.
</para>
</sect2>
</para>
</sect2>
+ <sect2 id="datatype-interval-input">
+ <title>Interval Input</title>
+
+ <indexterm>
+ <primary>interval</primary>
+ </indexterm>
+
+ <para>
+ <type>interval</type> values can be written with the following
+ verbose syntax:
+
+<programlisting>
+<optional>@</> <replaceable>quantity</> <replaceable>unit</> <optional><replaceable>quantity</> <replaceable>unit</>...</> <optional><replaceable>direction</></optional>
+</programlisting>
+
+ where <replaceable>quantity</> is a number (possibly signed);
+ <replaceable>unit</> is <literal>microsecond</literal>,
+ <literal>millisecond</literal>, <literal>second</literal>,
+ <literal>minute</literal>, <literal>hour</literal>, <literal>day</literal>,
+ <literal>week</literal>, <literal>month</literal>, <literal>year</literal>,
+ <literal>decade</literal>, <literal>century</literal>, <literal>millennium</literal>,
+ or abbreviations or plurals of these units;
+ <replaceable>direction</> can be <literal>ago</literal> or
+ empty. The at sign (<literal>@</>) is optional noise. The amounts
+ of different units are implicitly added up with appropriate
+ sign accounting. <literal>ago</literal> negates all the fields.
+ This syntax is also used for interval output, if
+ <xref linkend="guc-intervalstyle"> is set to
+ <literal>postgres_verbose</>.
+ </para>
+
+ <para>
+ Quantities of days, hours, minutes, and seconds can be specified without
+ explicit unit markings. For example, <literal>'1 12:59:10'</> is read
+ the same as <literal>'1 day 12 hours 59 min 10 sec'</>. Also,
+ a combination of years and months can be specified with a dash;
+ for example <literal>'200-10'</> is read the same as <literal>'200 years
+ 10 months'</>. (These shorter forms are in fact the only ones allowed
+ by the <acronym>SQL</acronym> standard, and are used for output when
+ <varname>IntervalStyle</> is set to <literal>sql_standard</literal>.)
+ </para>
+
+ <para>
+ When writing an interval constant with a <replaceable>fields</>
+ specification, or when assigning to an interval column that was defined
+ with a <replaceable>fields</> specification, the interpretation of
+ unmarked quantities depends on the <replaceable>fields</>. For
+ example <literal>INTERVAL '1' YEAR</> is read as 1 year, whereas
+ <literal>INTERVAL '1'</> means 1 second.
+ </para>
+
+ <para>
+ According to the <acronym>SQL</> standard all fields of an interval
+ value must have the same sign, so a leading negative sign applies to all
+ fields; for example the negative sign in the interval literal
+ <literal>'-1 2:03:04'</> applies to both the days and hour/minute/second
+ parts. <productname>PostgreSQL</> allows the fields to have different
+ signs, and traditionally treats each field in the textual representation
+ as independently signed, so that the hour/minute/second part is
+ considered positive in this example. If <varname>IntervalStyle</> is
+ set to <literal>sql_standard</literal> then a leading sign is considered
+ to apply to all fields (but only if no additional signs appear).
+ Otherwise the traditional <productname>PostgreSQL</> interpretation is
+ used. To avoid ambiguity, it's recommended to attach an explicit sign
+ to each field if any field is negative.
+ </para>
+
+ <para>
+ Internally <type>interval</> values are stored as months, days,
+ and seconds. This is done because the number of days in a month
+ varies, and a day can have 23 or 25 hours if a daylight savings
+ time adjustment is involved. Because intervals are usually created
+ from constant strings or <type>timestamp</> subtraction, this
+ storage method works well in most cases. Functions
+ <function>justify_days</> and <function>justify_hours</> are
+ available for adjusting days and hours that overflow their normal
+ ranges.
+ </para>
+ </sect2>
+
+ <sect2 id="datatype-interval-output">
+ <title>Interval Output</title>
+
+ <indexterm>
+ <primary>interval</primary>
+ <secondary>output format</secondary>
+ <seealso>formatting</seealso>
+ </indexterm>
+
+ <para>
+ The output format of the interval type can be set to one of the
+ three styles <literal>sql_standard</>,
+ <literal>postgres</>, or <literal>postgres_verbose</>,
+ using the command <literal>SET intervalstyle</literal>.
+ The default is the <literal>postgres</> format.
+ <xref linkend="interval-style-output-table"> shows examples of each
+ output style.
+ </para>
+
+ <para>
+ The <literal>sql_standard</> style produces output that conforms to
+ the SQL standard's specification for interval literal strings, if
+ the interval value meets the standard's restrictions (either year-month
+ only or day-time only, with no mixing of positive
+ and negative components). Otherwise the output looks like a standard
+ year-month literal string followed by a day-time literal string,
+ with explicit signs added to disambiguate mixed-sign intervals.
+ </para>
+
+ <para>
+ The output of the <literal>postgres</> style matches the output of
+ <productname>PostgreSQL</> releases prior to 8.4 when the
+ <xref linkend="guc-datestyle"> parameter was set to <literal>ISO</>.
+ </para>
+
+ <para>
+ The output of the <literal>postgres_verbose</> style matches the output of
+ <productname>PostgreSQL</> releases prior to 8.4 when the
+ <varname>DateStyle</> parameter was set to non-<literal>ISO</> output.
+ </para>
+
+ <table id="interval-style-output-table">
+ <title>Interval Output Style Examples</title>
+ <tgroup cols="4">
+ <thead>
+ <row>
+ <entry>Style Specification</entry>
+ <entry>Year-Month Interval</entry>
+ <entry>Day-Time Interval</entry>
+ <entry>Mixed Interval</entry>
+ </row>
+ </thead>
+ <tbody>
+ <row>
+ <entry><literal>sql_standard</></entry>
+ <entry>1-2</entry>
+ <entry>3 4:05:06</entry>
+ <entry>-1-2 +3 -4:05:06</entry>
+ </row>
+ <row>
+ <entry><literal>postgres</></entry>
+ <entry>1 year 2 mons</entry>
+ <entry>3 days 04:05:06</entry>
+ <entry>-1 year -2 mons +3 days -04:05:06</entry>
+ </row>
+ <row>
+ <entry><literal>postgres_verbose</></entry>
+ <entry>@ 1 year 2 mons</entry>
+ <entry>@ 3 days 4 hours 5 mins 6 secs</entry>
+ <entry>@ 1 year 2 mons -3 days 4 hours 5 mins 6 secs ago</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </table>
+
+ </sect2>
+
<sect2 id="datatype-datetime-internals">
<title>Internals</title>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/libpq.sgml,v 1.267 2008/11/04 22:36:07 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/libpq.sgml,v 1.268 2008/11/09 00:28:34 tgl Exp $ -->
<chapter id="libpq">
<title><application>libpq</application> - C Library</title>
<literal>is_superuser</>,
<literal>session_authorization</>,
<literal>DateStyle</>,
+ <literal>IntervalStyle</>,
<literal>TimeZone</>,
<literal>integer_datetimes</>, and
<literal>standard_conforming_strings</>.
(<literal>server_encoding</>, <literal>TimeZone</>, and
<literal>integer_datetimes</> were not reported by releases before 8.0;
<literal>standard_conforming_strings</> was not reported by releases
- before 8.1.)
+ before 8.1; <literal>IntervalStyle</> was not reported by releases
+ before 8.4.)
Note that
<literal>server_version</>,
<literal>server_encoding</> and
</para>
</listitem>
+ <listitem>
+ <para>
+ <indexterm>
+ <primary><envar>PGINTERVALSTYLE</envar></primary>
+ </indexterm>
+ <envar>PGINTERVALSTYLE</envar> sets the default style of interval
+ representation. (Equivalent to <literal>SET intervalstyle TO
+ ...</literal>.)
+ </para>
+ </listitem>
+
<listitem>
<para>
<indexterm>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/protocol.sgml,v 1.74 2008/10/28 12:10:42 mha Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/protocol.sgml,v 1.75 2008/11/09 00:28:34 tgl Exp $ -->
<chapter id="protocol">
<title>Frontend/Backend Protocol</title>
<literal>is_superuser</>,
<literal>session_authorization</>,
<literal>DateStyle</>,
+ <literal>IntervalStyle</>,
<literal>TimeZone</>,
<literal>integer_datetimes</>, and
<literal>standard_conforming_strings</>.
(<literal>server_encoding</>, <literal>TimeZone</>, and
<literal>integer_datetimes</> were not reported by releases before 8.0;
<literal>standard_conforming_strings</> was not reported by releases
- before 8.1.)
+ before 8.1; <literal>IntervalStyle</> was not reported by releases
+ before 8.4.)
Note that
<literal>server_version</>,
<literal>server_encoding</> and
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.82 2008/10/10 21:46:34 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.83 2008/11/09 00:28:34 tgl Exp $
PostgreSQL documentation
-->
<productname>PostgreSQL</productname> installations that might use
non-default <varname>DateStyle</varname> settings,
<varname>DateStyle</varname> should be set to <literal>ISO</> before
- using <command>COPY TO</>.
+ using <command>COPY TO</>. It is also a good idea to avoid dumping
+ data with <varname>IntervalStyle</varname> set to
+ <literal>sql_standard</>, because negative interval values might be
+ misinterpreted by a server that has a different setting for
+ <varname>IntervalStyle</varname>.
</para>
<para>
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/adt/datetime.c,v 1.196 2008/11/08 20:51:49 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/adt/datetime.c,v 1.197 2008/11/09 00:28:34 tgl Exp $
*
*-------------------------------------------------------------------------
*/
fmask |= tmask;
}
+ /* ensure that at least one time field has been found */
+ if (fmask == 0)
+ return DTERR_BAD_FORMAT;
+
+ /* ensure fractional seconds are fractional */
if (*fsec != 0)
{
int sec;
tm->tm_sec += sec;
}
+ /*----------
+ * The SQL standard defines the interval literal
+ * '-1 1:00:00'
+ * to mean "negative 1 days and negative 1 hours", while Postgres
+ * traditionally treats this as meaning "negative 1 days and positive
+ * 1 hours". In SQL_STANDARD intervalstyle, we apply the leading sign
+ * to all fields if there are no other explicit signs.
+ *
+ * We leave the signs alone if there are additional explicit signs.
+ * This protects us against misinterpreting postgres-style dump output,
+ * since the postgres-style output code has always put an explicit sign on
+ * all fields following a negative field. But note that SQL-spec output
+ * is ambiguous and can be misinterpreted on load! (So it's best practice
+ * to dump in postgres style, not SQL style.)
+ *----------
+ */
+ if (IntervalStyle == INTSTYLE_SQL_STANDARD && *field[0] == '-')
+ {
+ /* Check for additional explicit signs */
+ bool more_signs = false;
+
+ for (i = 1; i < nf; i++)
+ {
+ if (*field[i] == '-' || *field[i] == '+')
+ {
+ more_signs = true;
+ break;
+ }
+ }
+
+ if (!more_signs)
+ {
+ /*
+ * Rather than re-determining which field was field[0], just
+ * force 'em all negative.
+ */
+ if (*fsec > 0)
+ *fsec = -(*fsec);
+ if (tm->tm_sec > 0)
+ tm->tm_sec = -tm->tm_sec;
+ if (tm->tm_min > 0)
+ tm->tm_min = -tm->tm_min;
+ if (tm->tm_hour > 0)
+ tm->tm_hour = -tm->tm_hour;
+ if (tm->tm_mday > 0)
+ tm->tm_mday = -tm->tm_mday;
+ if (tm->tm_mon > 0)
+ tm->tm_mon = -tm->tm_mon;
+ if (tm->tm_year > 0)
+ tm->tm_year = -tm->tm_year;
+ }
+ }
+
+ /* finally, AGO negates everything */
if (is_before)
{
*fsec = -(*fsec);
tm->tm_year = -tm->tm_year;
}
- /* ensure that at least one time field has been found */
- if (fmask == 0)
- return DTERR_BAD_FORMAT;
-
return 0;
}
}
+/*
+ * Helper function to avoid duplicated code in EncodeInterval below.
+ * Note that any sign is stripped from the input seconds values.
+ */
+static void
+AppendSeconds(char *cp, int sec, fsec_t fsec)
+{
+ if (fsec == 0)
+ {
+ sprintf(cp, ":%02d", abs(sec));
+ }
+ else
+ {
+#ifdef HAVE_INT64_TIMESTAMP
+ sprintf(cp, ":%02d.%06d", abs(sec), Abs(fsec));
+#else
+ sprintf(cp, ":%012.9f", fabs(sec + fsec));
+#endif
+ TrimTrailingZeros(cp);
+ }
+}
+
+
/* EncodeInterval()
* Interpret time structure as a delta time and convert to string.
*
* Actually, afaik ISO does not address time interval formatting,
* but this looks similar to the spec for absolute date/time.
* - thomas 1998-04-30
+ *
+ * Actually, afaik, ISO 8601 does specify formats for "time
+ * intervals...[of the]...format with time-unit designators", which
+ * are pretty ugly. The format looks something like
+ * P1Y1M1DT1H1M1.12345S
+ * but useful for exchanging data with computers instead of humans.
+ * - ron 2003-07-14
+ *
+ * And ISO's SQL 2008 standard specifies standards for
+ * "year-month literal"s (that look like '2-3') and
+ * "day-time literal"s (that look like ('4 5:6:7')
*/
int
EncodeInterval(struct pg_tm * tm, fsec_t fsec, int style, char *str)
{
+ char *cp = str;
+ int year = tm->tm_year;
+ int mon = tm->tm_mon;
+ int mday = tm->tm_mday;
+ int hour = tm->tm_hour;
+ int min = tm->tm_min;
+ int sec = tm->tm_sec;
bool is_before = FALSE;
bool is_nonzero = FALSE;
- char *cp = str;
/*
* The sign of year and month are guaranteed to match, since they are
* stored internally as "month". But we'll need to check for is_before and
- * is_nonzero when determining the signs of hour/minute/seconds fields.
+ * is_nonzero when determining the signs of day and hour/minute/seconds
+ * fields.
*/
switch (style)
{
- /* compatible with ISO date formats */
- case USE_ISO_DATES:
+ /* SQL Standard interval format */
+ case INTSTYLE_SQL_STANDARD:
+ {
+ bool has_negative = year < 0 || mon < 0 ||
+ mday < 0 || hour < 0 ||
+ min < 0 || sec < 0 || fsec < 0;
+ bool has_positive = year > 0 || mon > 0 ||
+ mday > 0 || hour > 0 ||
+ min > 0 || sec > 0 || fsec > 0;
+ bool has_year_month = year != 0 || mon != 0;
+ bool has_day_time = mday != 0 || hour != 0 ||
+ min != 0 || sec != 0 || fsec != 0;
+ bool has_day = mday != 0;
+ bool sql_standard_value = !(has_negative && has_positive) &&
+ !(has_year_month && has_day_time);
+
+ /*
+ * SQL Standard wants only 1 "<sign>" preceding the whole
+ * interval ... but can't do that if mixed signs.
+ */
+ if (has_negative && sql_standard_value)
+ {
+ *cp++ = '-';
+ year = -year;
+ mon = -mon;
+ mday = -mday;
+ hour = -hour;
+ min = -min;
+ sec = -sec;
+ fsec = -fsec;
+ }
+
+ if (!has_negative && !has_positive)
+ {
+ sprintf(cp, "0");
+ }
+ else if (!sql_standard_value)
+ {
+ /*
+ * For non sql-standard interval values,
+ * force outputting the signs to avoid
+ * ambiguities with intervals with mixed
+ * sign components.
+ */
+ char year_sign = (year < 0 || mon < 0) ? '-' : '+';
+ char day_sign = (mday < 0) ? '-' : '+';
+ char sec_sign = (hour < 0 || min < 0 || sec < 0 || fsec < 0) ? '-' : '+';
+
+ sprintf(cp, "%c%d-%d %c%d %c%d:%02d",
+ year_sign, abs(year), abs(mon),
+ day_sign, abs(mday),
+ sec_sign, abs(hour), abs(min));
+ cp += strlen(cp);
+ AppendSeconds(cp, sec, fsec);
+ }
+ else if (has_year_month)
+ {
+ sprintf(cp, "%d-%d", year, mon);
+ }
+ else if (has_day)
+ {
+ sprintf(cp, "%d %d:%02d", mday, hour, min);
+ cp += strlen(cp);
+ AppendSeconds(cp, sec, fsec);
+ }
+ else
+ {
+ sprintf(cp, "%d:%02d", hour, min);
+ cp += strlen(cp);
+ AppendSeconds(cp, sec, fsec);
+ }
+ }
+ break;
+
+ /* Compatible with postgresql < 8.4 when DateStyle = 'iso' */
+ case INTSTYLE_POSTGRES:
if (tm->tm_year != 0)
{
sprintf(cp, "%d year%s",
(minus ? "-" : (is_before ? "+" : "")),
abs(tm->tm_hour), abs(tm->tm_min));
cp += strlen(cp);
- /* Mark as "non-zero" since the fields are now filled in */
+ AppendSeconds(cp, tm->tm_sec, fsec);
+ cp += strlen(cp);
is_nonzero = TRUE;
-
- /* need fractional seconds? */
- if (fsec != 0)
- {
-#ifdef HAVE_INT64_TIMESTAMP
- sprintf(cp, ":%02d", abs(tm->tm_sec));
- cp += strlen(cp);
- sprintf(cp, ".%06d", Abs(fsec));
-#else
- fsec += tm->tm_sec;
- sprintf(cp, ":%012.9f", fabs(fsec));
-#endif
- TrimTrailingZeros(cp);
- cp += strlen(cp);
- }
- else
- {
- sprintf(cp, ":%02d", abs(tm->tm_sec));
- cp += strlen(cp);
- }
+ }
+ /* identically zero? then put in a unitless zero... */
+ if (!is_nonzero)
+ {
+ strcat(cp, "0");
+ cp += strlen(cp);
}
break;
- case USE_POSTGRES_DATES:
+ /* Compatible with postgresql < 8.4 when DateStyle != 'iso' */
+ case INTSTYLE_POSTGRES_VERBOSE:
default:
strcpy(cp, "@ ");
cp += strlen(cp);
is_before = (tm->tm_sec < 0);
is_nonzero = TRUE;
}
+ /* identically zero? then put in a unitless zero... */
+ if (!is_nonzero)
+ {
+ strcat(cp, "0");
+ cp += strlen(cp);
+ }
+ if (is_before)
+ {
+ strcat(cp, " ago");
+ cp += strlen(cp);
+ }
break;
}
- /* identically zero? then put in a unitless zero... */
- if (!is_nonzero)
- {
- strcat(cp, "0");
- cp += strlen(cp);
- }
-
- if (is_before && (style != USE_ISO_DATES))
- {
- strcat(cp, " ago");
- cp += strlen(cp);
- }
-
return 0;
} /* EncodeInterval() */
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/adt/nabstime.c,v 1.156 2008/09/10 18:29:41 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/adt/nabstime.c,v 1.157 2008/11/09 00:28:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
char buf[MAXDATELEN + 1];
reltime2tm(time, tm);
- EncodeInterval(tm, 0, DateStyle, buf);
+ EncodeInterval(tm, 0, IntervalStyle, buf);
result = pstrdup(buf);
PG_RETURN_CSTRING(result);
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.193 2008/10/14 15:44:29 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.194 2008/11/09 00:28:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
if (interval2tm(*span, tm, &fsec) != 0)
elog(ERROR, "could not convert interval to tm");
- if (EncodeInterval(tm, fsec, DateStyle, buf) != 0)
+ if (EncodeInterval(tm, fsec, IntervalStyle, buf) != 0)
elog(ERROR, "could not format interval");
result = pstrdup(buf);
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/init/globals.c,v 1.105 2008/02/17 02:09:29 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/init/globals.c,v 1.106 2008/11/09 00:28:35 tgl Exp $
*
* NOTES
* Globals used all over the place should be declared here and not
int DateStyle = USE_ISO_DATES;
int DateOrder = DATEORDER_MDY;
+int IntervalStyle = INTSTYLE_POSTGRES;
bool HasCTZSet = false;
int CTimeZone = 0;
* Written by Peter Eisentraut <peter_e@gmx.net>.
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/misc/guc.c,v 1.475 2008/10/06 13:05:36 mha Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/misc/guc.c,v 1.476 2008/11/09 00:28:35 tgl Exp $
*
*--------------------------------------------------------------------
*/
{NULL, 0, false}
};
+static const struct config_enum_entry intervalstyle_options[] = {
+ {"postgres", INTSTYLE_POSTGRES, false},
+ {"postgres_verbose", INTSTYLE_POSTGRES_VERBOSE, false},
+ {"sql_standard", INTSTYLE_SQL_STANDARD, false},
+ {NULL, 0, false}
+};
+
static const struct config_enum_entry log_error_verbosity_options[] = {
{"terse", PGERROR_TERSE, false},
{"default", PGERROR_DEFAULT, false},
XACT_READ_COMMITTED, isolation_level_options, NULL, NULL
},
+ {
+ {"IntervalStyle", PGC_USERSET, CLIENT_CONN_LOCALE,
+ gettext_noop("Sets the display format for interval values."),
+ NULL,
+ GUC_REPORT
+ },
+ &IntervalStyle,
+ INTSTYLE_POSTGRES, intervalstyle_options, NULL, NULL
+ },
+
{
{"log_error_verbosity", PGC_SUSET, LOGGING_WHEN,
gettext_noop("Sets the verbosity of logged messages."),
# - Locale and Formatting -
#datestyle = 'iso, mdy'
+#intervalstyle = 'postgres'
#timezone = unknown # actually, defaults to TZ environment
# setting
#timezone_abbreviations = 'Default' # Select the set of available time zone
* by PostgreSQL
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.c,v 1.503 2008/10/31 08:39:21 heikki Exp $
+ * $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.c,v 1.504 2008/11/09 00:28:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
/* Set the datestyle to ISO to ensure the dump's portability */
do_sql_command(g_conn, "SET DATESTYLE = ISO");
+ /* Likewise, avoid using sql_standard intervalstyle */
+ if (g_fout->remoteVersion >= 80400)
+ do_sql_command(g_conn, "SET INTERVALSTYLE = POSTGRES");
+
/*
* If supported, set extra_float_digits so that we can dump float data
* exactly (given correctly implemented float I/O code, anyway)
*
* Copyright (c) 2000-2008, PostgreSQL Global Development Group
*
- * $PostgreSQL: pgsql/src/bin/psql/tab-complete.c,v 1.174 2008/11/07 18:25:07 tgl Exp $
+ * $PostgreSQL: pgsql/src/bin/psql/tab-complete.c,v 1.175 2008/11/09 00:28:35 tgl Exp $
*/
/*----------------------------------------------------------------------
COMPLETE_WITH_LIST(my_list);
}
+ else if (pg_strcasecmp(prev2_wd, "IntervalStyle") == 0)
+ {
+ static const char *const my_list[] =
+ {"postgres", "postgres_verbose", "sql_standard", NULL};
+
+ COMPLETE_WITH_LIST(my_list);
+ }
else if (pg_strcasecmp(prev2_wd, "GEQO") == 0)
{
static const char *const my_list[] =
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
- * $PostgreSQL: pgsql/src/include/miscadmin.h,v 1.203 2008/10/09 17:24:05 alvherre Exp $
+ * $PostgreSQL: pgsql/src/include/miscadmin.h,v 1.204 2008/11/09 00:28:35 tgl Exp $
*
* NOTES
* some of the information in this file should be moved to other files.
extern int DateStyle;
extern int DateOrder;
+
+/*
+ * IntervalStyles
+ * INTSTYLE_POSTGRES Like Postgres < 8.4 when DateStyle = 'iso'
+ * INTSTYLE_POSTGRES_VERBOSE Like Postgres < 8.4 when DateStyle != 'iso'
+ * INTSTYLE_SQL_STANDARD SQL standard interval literals
+ */
+#define INTSTYLE_POSTGRES 0
+#define INTSTYLE_POSTGRES_VERBOSE 1
+#define INTSTYLE_SQL_STANDARD 2
+
+extern int IntervalStyle;
/*
* HasCTZSet is true if user has set timezone as a numeric offset from UTC.
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/interfaces/libpq/fe-connect.c,v 1.366 2008/11/03 14:18:57 mha Exp $
+ * $PostgreSQL: pgsql/src/interfaces/libpq/fe-connect.c,v 1.367 2008/11/09 00:28:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
{
"PGDATESTYLE", "datestyle"
},
+ {
+ "PGINTERVALSTYLE", "intervalstyle"
+ },
{
"PGTZ", "timezone"
},
-- INTERVAL
--
SET DATESTYLE = 'ISO';
+SET IntervalStyle to postgres;
-- check acceptance of "time zone style"
SELECT INTERVAL '01:00' AS "One hour";
One hour
DROP TABLE INTERVAL_MULDIV_TBL;
SET DATESTYLE = 'postgres';
+SET IntervalStyle to postgres_verbose;
SELECT '' AS ten, * FROM INTERVAL_TBL;
ten | f1
-----+-------------------------------
-- test fractional second input, and detection of duplicate units
SET DATESTYLE = 'ISO';
+SET IntervalStyle TO postgres;
SELECT '1 millisecond'::interval, '1 microsecond'::interval,
'500 seconds 99 milliseconds 51 microseconds'::interval;
interval | interval | interval
00:03:04.57
(1 row)
+-- test inputting and outputting SQL standard interval literals
+SET IntervalStyle TO sql_standard;
+SELECT interval '0' AS "zero",
+ interval '1-2' year to month AS "year-month",
+ interval '1 2:03:04' day to second AS "day-time",
+ - interval '1-2' AS "negative year-month",
+ - interval '1 2:03:04' AS "negative day-time";
+ zero | year-month | day-time | negative year-month | negative day-time
+------+------------+-----------+---------------------+-------------------
+ 0 | 1-2 | 1 2:03:04 | -1-2 | -1 2:03:04
+(1 row)
+
+-- test input of some not-quite-standard interval values in the sql style
+SET IntervalStyle TO postgres;
+SELECT interval '+1 -1:00:00',
+ interval '-1 +1:00:00',
+ interval '+1-2 -3 +4:05:06.789',
+ interval '-1-2 +3 -4:05:06.789';
+ interval | interval | interval | interval
+-----------------+-------------------+-------------------------------------+----------------------------------------
+ 1 day -01:00:00 | -1 days +01:00:00 | 1 year 2 mons -3 days +04:05:06.789 | -1 years -2 mons +3 days -04:05:06.789
+(1 row)
+
+-- test output of couple non-standard interval values in the sql style
+SET IntervalStyle TO sql_standard;
+SELECT interval '1 day -1 hours',
+ interval '-1 days +1 hours',
+ interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds',
+ - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds';
+ interval | interval | interval | ?column?
+------------------+------------------+----------------------+----------------------
+ +0-0 +1 -1:00:00 | +0-0 -1 +1:00:00 | +1-2 -3 +4:05:06.789 | -1-2 +3 -4:05:06.789
+(1 row)
+
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
- * $PostgreSQL: pgsql/src/test/regress/pg_regress.c,v 1.48 2008/10/01 22:38:57 petere Exp $
+ * $PostgreSQL: pgsql/src/test/regress/pg_regress.c,v 1.49 2008/11/09 00:28:35 tgl Exp $
*
*-------------------------------------------------------------------------
*/
*/
putenv("PGTZ=PST8PDT");
putenv("PGDATESTYLE=Postgres, MDY");
+ putenv("PGINTERVALSTYLE=postgres_verbose");
if (temp_install)
{
--
SET DATESTYLE = 'ISO';
+SET IntervalStyle to postgres;
-- check acceptance of "time zone style"
SELECT INTERVAL '01:00' AS "One hour";
DROP TABLE INTERVAL_MULDIV_TBL;
SET DATESTYLE = 'postgres';
+SET IntervalStyle to postgres_verbose;
SELECT '' AS ten, * FROM INTERVAL_TBL;
-- test fractional second input, and detection of duplicate units
SET DATESTYLE = 'ISO';
+SET IntervalStyle TO postgres;
+
SELECT '1 millisecond'::interval, '1 microsecond'::interval,
'500 seconds 99 milliseconds 51 microseconds'::interval;
SELECT '3 days 5 milliseconds'::interval;
SELECT interval '1 2.3456' minute to second(2);
SELECT interval '1 2:03.5678' minute to second(2);
SELECT interval '1 2:03:04.5678' minute to second(2);
+
+-- test inputting and outputting SQL standard interval literals
+SET IntervalStyle TO sql_standard;
+SELECT interval '0' AS "zero",
+ interval '1-2' year to month AS "year-month",
+ interval '1 2:03:04' day to second AS "day-time",
+ - interval '1-2' AS "negative year-month",
+ - interval '1 2:03:04' AS "negative day-time";
+
+-- test input of some not-quite-standard interval values in the sql style
+SET IntervalStyle TO postgres;
+SELECT interval '+1 -1:00:00',
+ interval '-1 +1:00:00',
+ interval '+1-2 -3 +4:05:06.789',
+ interval '-1-2 +3 -4:05:06.789';
+
+-- test output of couple non-standard interval values in the sql style
+SET IntervalStyle TO sql_standard;
+SELECT interval '1 day -1 hours',
+ interval '-1 days +1 hours',
+ interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds',
+ - interval '1 years 2 months -3 days 4 hours 5 minutes 6.789 seconds';