From 4dc8a0e4e18c8d064d2dc90a4bd957123434df76 Mon Sep 17 00:00:00 2001 From: Tom Lane <tgl@sss.pgh.pa.us> Date: Thu, 21 Nov 2002 23:31:37 +0000 Subject: [PATCH] Fix breakage in new-in-7.3 timetz_zone() function: was giving random results due to doing arithmetic on uninitialized values. Add some documentation about the AT TIME ZONE construct. Update some other date/time documentation that seemed out of date for 7.3. --- doc/src/sgml/datatype.sgml | 314 ++++++++++++++++++++--------------- doc/src/sgml/func.sgml | 124 ++++++++++++-- src/backend/utils/adt/date.c | 21 +-- 3 files changed, 308 insertions(+), 151 deletions(-) diff --git a/doc/src/sgml/datatype.sgml b/doc/src/sgml/datatype.sgml index 1e247ec033e..c81c0bb9700 100644 --- a/doc/src/sgml/datatype.sgml +++ b/doc/src/sgml/datatype.sgml @@ -1,5 +1,5 @@ <!-- -$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106.2.1 2002/11/10 12:45:41 petere Exp $ +$Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106.2.2 2002/11/21 23:31:37 tgl Exp $ --> <chapter id="datatype"> @@ -245,14 +245,15 @@ $Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106.2.1 2002/11/10 12:45: <note> <title>Compatibility</title> <para> - The following types (or spellings thereof) are specified by SQL: - <type>bit</type>, <type>bit varying</type>, <type>boolean</type>, - <type>char</type>, <type>character</type>, <type>character - varying</type>, <type>varchar</type>, <type>date</type>, - <type>double precision</type>, <type>integer</type>, - <type>interval</type>, <type>numeric</type>, <type>decimal</type>, - <type>real</type>, <type>smallint</type>, <type>time</type>, - <type>timestamp</type> (both with or without time zone). + The following types (or spellings thereof) are specified by + <acronym>SQL</acronym>: <type>bit</type>, <type>bit + varying</type>, <type>boolean</type>, <type>char</type>, + <type>character</type>, <type>character varying</type>, + <type>varchar</type>, <type>date</type>, <type>double + precision</type>, <type>integer</type>, <type>interval</type>, + <type>numeric</type>, <type>decimal</type>, <type>real</type>, + <type>smallint</type>, <type>time</type>, <type>timestamp</type> + (both with or without time zone). </para> </note> @@ -464,11 +465,12 @@ $Header: /cvsroot/pgsql/doc/src/sgml/datatype.sgml,v 1.106.2.1 2002/11/10 12:45: </para> <para> - SQL only specifies the integer types <type>integer</type> (or - <type>int</type>) and <type>smallint</type>. The type - <type>bigint</type>, and the type names <type>int2</type>, - <type>int4</type>, and <type>int8</type> are extensions, which - are shared with various other SQL database systems. + <acronym>SQL</acronym> only specifies the integer types + <type>integer</type> (or <type>int</type>) and + <type>smallint</type>. The type <type>bigint</type>, and the + type names <type>int2</type>, <type>int4</type>, and + <type>int8</type> are extensions, which are shared with various + other <acronym>SQL</acronym> database systems. </para> <note> @@ -536,13 +538,15 @@ NUMERIC(<replaceable>precision</replaceable>) NUMERIC </programlisting> without any precision or scale creates a column in which numeric - values of any precision and scale can be stored, up to the implementation - limit on precision. A column of this kind will not coerce input - values to any particular scale, whereas <type>numeric</type> columns - with a declared scale will coerce input values to that scale. - (The SQL standard requires a default scale of 0, i.e., coercion to - integer precision. We find this a bit useless. If you're concerned about - portability, always specify the precision and scale explicitly.) + values of any precision and scale can be stored, up to the + implementation limit on precision. A column of this kind will + not coerce input values to any particular scale, whereas + <type>numeric</type> columns with a declared scale will coerce + input values to that scale. (The <acronym>SQL</acronym> standard + requires a default scale of 0, i.e., coercion to integer + precision. We find this a bit useless. If you're concerned + about portability, always specify the precision and scale + explicitly.) </para> <para> @@ -554,7 +558,8 @@ NUMERIC <para> The types <type>decimal</type> and <type>numeric</type> are - equivalent. Both types are part of the SQL standard. + equivalent. Both types are part of the <acronym>SQL</acronym> + standard. </para> </sect2> @@ -806,7 +811,8 @@ CREATE TABLE <replaceable class="parameter">tablename</replaceable> ( <para> <xref linkend="datatype-character-table"> shows the - general-purpose character types available in PostgreSQL. + general-purpose character types available in + <productname>PostgreSQL</productname>. </para> <para> @@ -818,11 +824,12 @@ CREATE TABLE <replaceable class="parameter">tablename</replaceable> ( longer string into a column of these types will result in an error, unless the excess characters are all spaces, in which case the string will be truncated to the maximum length. (This - somewhat bizarre exception is required by the SQL standard.) If - the string to be stored is shorter than the declared length, - values of type <type>character</type> will be space-padded; values - of type <type>character varying</type> will simply store the - shorter string. + somewhat bizarre exception is required by the + <acronym>SQL</acronym> standard.) If the string to be stored is + shorter than the declared length, values of type + <type>character</type> will be space-padded; values of type + <type>character varying</type> will simply store the shorter + string. </para> <note> @@ -831,7 +838,8 @@ CREATE TABLE <replaceable class="parameter">tablename</replaceable> ( <type>character(<replaceable>n</>)</type> or <type>character varying(<replaceable>n</>)</type>, then an overlength value will be truncated to <replaceable>n</> characters without raising an - error. (This too is required by the SQL standard.) + error. (This too is required by the <acronym>SQL</acronym> + standard.) </para> </note> @@ -859,8 +867,9 @@ CREATE TABLE <replaceable class="parameter">tablename</replaceable> ( more general <type>text</type> type, which stores strings of any length. Unlike <type>character varying</type>, <type>text</type> does not require an explicit declared upper limit on the size of - the string. Although the type <type>text</type> is not in the SQL - standard, many other RDBMS packages have it as well. + the string. Although the type <type>text</type> is not in the + <acronym>SQL</acronym> standard, many other RDBMS packages have it + as well. </para> <para> @@ -1125,12 +1134,12 @@ SELECT b, char_length(b) FROM test2; <para> To use the <type>bytea</type> escaped octet notation, string - literals (input strings) must contain two backslashes due because - they must pass through two parsers in the PostgreSQL server. The - first backslash is interpreted as an escape character by the - string-literal parser, and therefore is consumed, leaving the - characters that follow. The remaining backslash is recognized by - the <type>bytea</type> input function as the prefix of a three + literals (input strings) must contain two backslashes because they + must pass through two parsers in the <productname>PostgreSQL</> + server. The first backslash is interpreted as an escape character + by the string-literal parser, and therefore is consumed, leaving + the characters that follow. The remaining backslash is recognized + by the <type>bytea</type> input function as the prefix of a three digit octal value. For example, a string literal passed to the backend as <literal>'\\001'</literal> becomes <literal>'\001'</literal> after passing through the string-literal @@ -1170,21 +1179,22 @@ SELECT b, char_length(b) FROM test2; </para> <para> - Depending on the front end to PostgreSQL you use, you may have - additional work to do in terms of escaping and unescaping - <type>bytea</type> strings. For example, you may also have to escape - line feeds and carriage returns if your interface automatically - translates these. Or you may have to double up on backslashes if - the parser for your language or choice also treats them as an - escape character. + Depending on the front end to <productname>PostgreSQL</> you use, + you may have additional work to do in terms of escaping and + unescaping <type>bytea</type> strings. For example, you may also + have to escape line feeds and carriage returns if your interface + automatically translates these. Or you may have to double up on + backslashes if the parser for your language or choice also treats + them as an escape character. </para> - <para> - The SQL standard defines a different binary string type, called - <type>BLOB</type> or <type>BINARY LARGE OBJECT</type>. The input - format is different compared to <type>bytea</type>, but the - provided functions and operators are mostly the same. - </para> + <para> + The <acronym>SQL</acronym> standard defines a different binary + string type, called <type>BLOB</type> or <type>BINARY LARGE + OBJECT</type>. The input format is different compared to + <type>bytea</type>, but the provided functions and operators are + mostly the same. + </para> </sect1> @@ -1559,20 +1569,32 @@ SELECT b, char_length(b) FROM test2; <secondary>data type</secondary> </indexterm> + <indexterm> + <primary>timestamp with time zone</primary> + <secondary>data type</secondary> + </indexterm> + <indexterm> <primary>timestamp without time zone</primary> <secondary>data type</secondary> </indexterm> <para> - Time stamp types exist as <type>timestamp [ - (<replaceable>p</replaceable>) ]</type>, <type>timestamp [ + The time stamp types are <type>timestamp [ (<replaceable>p</replaceable>) ] without time zone</type> and - <type>timestamp [ (<replaceable>p</replaceable>) ] without time - zone</type>. A plain <type>timestamp</type> is equivalent to - <type>timestamp without timezone</type>. + <type>timestamp [ (<replaceable>p</replaceable>) ] with time + zone</type>. Writing just <type>timestamp</type> is equivalent to + <type>timestamp without time zone</type>. </para> + <note> + <para> + Prior to <productname>PostgreSQL</productname> 7.3, writing just + <type>timestamp</type> was equivalent to <type>timestamp with time + zone</type>. This was changed for SQL spec compliance. + </para> + </note> + <para> Valid input for the time stamp types consists of a concatenation of a date and a time, followed by an optional @@ -1605,11 +1627,38 @@ January 8 04:05:06 1999 PST <para> For <type>timestamp without time zone</type>, any explicit time - zone specified in the input is silently swallowed. That is, the + zone specified in the input is silently ignored. That is, the resulting date/time value is derived from the explicit date/time fields in the input value, and is not adjusted for time zone. </para> + <para> + For <type>timestamp with time zone</type>, the internally stored + value is always in UTC (GMT). An input value that has an explicit + time zone specified is converted to UTC using the appropriate offset + for that time zone. If no time zone is stated in the input string, + then it is assumed to be in the time zone indicated by the system's + <varname>TimeZone</> parameter, and is converted to UTC using the + offset for the <varname>TimeZone</> zone. + </para> + + <para> + When a <type>timestamp with time + zone</type> value is output, it is always converted from UTC to the + current <varname>TimeZone</> zone, and displayed as local time in that + zone. To see the time in another time zone, either change + <varname>TimeZone</> or use the <literal>AT TIME ZONE</> construct + (see <xref linkend="functions-datetime-zoneconvert">). + </para> + + <para> + Conversions between <type>timestamp without time zone</type> and + <type>timestamp with time zone</type> normally assume that the + <type>timestamp without time zone</type> value should be taken or given + as <varname>TimeZone</> local time. A different zone reference can + be specified for the conversion using <literal>AT TIME ZONE</>. + </para> + <table tocentry="1" id="datatype-timezone-table"> <title>Time Zone Input</title> <tgroup cols="2"> @@ -1697,24 +1746,28 @@ January 8 04:05:06 1999 PST <para> The following <acronym>SQL</acronym>-compatible functions can be used as date or time - input for the corresponding data type: <literal>CURRENT_DATE</literal>, + values for the corresponding data type: <literal>CURRENT_DATE</literal>, <literal>CURRENT_TIME</literal>, <literal>CURRENT_TIMESTAMP</literal>. The latter two accept an - optional precision specification. (See also <xref linkend="functions-datetime">.) + optional precision specification. (See also <xref linkend="functions-datetime-current">.) </para> <para> <productname>PostgreSQL</productname> also supports several - special constants for convenience, shown in <xref - linkend="datatype-datetime-special-table">. + special date/time input values for convenience, as shown in <xref + linkend="datatype-datetime-special-table">. The values + <literal>infinity</literal> and <literal>-infinity</literal> + are specially represented inside the system and will be displayed + the same way; but the others are simply notational shorthands + that will be converted to ordinary date/time values when read. </para> <table id="datatype-datetime-special-table"> - <title>Special Date/Time Constants</title> + <title>Special Date/Time Inputs</title> <tgroup cols="2"> <thead> <row> - <entry>Constant</entry> + <entry>Input string</entry> <entry>Description</entry> </row> </thead> @@ -1725,15 +1778,13 @@ January 8 04:05:06 1999 PST </row> <row> <entry><literal>infinity</literal></entry> - <entry>later than other valid times</entry> + <entry>later than all other timestamps (not available for + type <type>date</>)</entry> </row> <row> <entry><literal>-infinity</literal></entry> - <entry>earlier than other valid times</entry> - </row> - <row> - <entry><literal>invalid</literal></entry> - <entry>illegal entry</entry> + <entry>earlier than all other timestamps (not available for + type <type>date</>)</entry> </row> <row> <entry><literal>now</literal></entry> @@ -1781,11 +1832,12 @@ January 8 04:05:06 1999 PST Output formats can be set to one of the four styles ISO 8601, <acronym>SQL</acronym> (Ingres), traditional PostgreSQL, and German, using the <command>SET DateStyle</command>. The default - is the <acronym>ISO</acronym> format. (The SQL standard requires - the use of the ISO 8601 format. The name of the - <quote>SQL</quote> output format is a historical accident.) - <xref linkend="datatype-datetime-output-table"> shows examples of - each output style. The output of the <type>date</type> and + is the <acronym>ISO</acronym> format. (The + <acronym>SQL</acronym> standard requires the use of the ISO 8601 + format. The name of the <quote>SQL</quote> output format is a + historical accident.) <xref + linkend="datatype-datetime-output-table"> shows examples of each + output style. The output of the <type>date</type> and <type>time</type> types is of course only the date or time part in accordance with the given examples. </para> @@ -1920,44 +1972,52 @@ January 8 04:05:06 1999 PST </para> <para> - To address these difficulties, we recommend using date/time - types that contain both date and time when using time zones. We - recommend <emphasis>not</emphasis> using the type <type>time - with time zone</type> (though it is supported by + To address these difficulties, we recommend using date/time types + that contain both date and time when using time zones. We + recommend <emphasis>not</emphasis> using the type <type>time with + time zone</type> (though it is supported by <productname>PostgreSQL</productname> for legacy applications and - for compatibility with other SQL implementations). - <productname>PostgreSQL</productname> - assumes your local time zone for any type containing only - date or time. Further, time zone support is derived from - the underlying operating system - time-zone capabilities, and hence can handle daylight-saving time - and other expected behavior. + for compatibility with other <acronym>SQL</acronym> + implementations). <productname>PostgreSQL</productname> assumes + your local time zone for any type containing only date or + time. Further, time zone support is derived from the underlying + operating system time-zone capabilities, and hence can handle + daylight-saving time and other expected behavior. </para> <para> - <productname>PostgreSQL</productname> obtains time-zone support + <productname>PostgreSQL</productname> obtains time-zone support from the underlying operating system for dates between 1902 and 2038 (near the typical date limits for Unix-style systems). Outside of this range, all dates are assumed to be - specified and used in Universal Coordinated Time (UTC). + specified and used in Universal Coordinated Time + (<acronym>UTC</acronym>). </para> <para> - All dates and times are stored internally in UTC, - traditionally known as Greenwich Mean Time (GMT). - Times are converted to local time on the database server before being - sent to the client frontend, hence by default are in the server - time zone. + All dates and times are stored internally in + <acronym>UTC</acronym>, traditionally known as Greenwich Mean + Time (<acronym>GMT</acronym>). Times are converted to local time + on the database server before being sent to the client frontend, + hence by default are in the server time zone. </para> <para> - There are several ways to affect the time-zone behavior: + There are several ways to select the time zone used by the server: <itemizedlist> <listitem> <para> The <envar>TZ</envar> environment variable on the server host - is used by the server as the default time zone. + is used by the server as the default time zone, if no other is + specified. + </para> + </listitem> + + <listitem> + <para> + The <varname>timezone</varname> configuration parameter can be + set in <filename>postgresql.conf</>. </para> </listitem> @@ -1976,25 +2036,13 @@ January 8 04:05:06 1999 PST sets the time zone for the session. </para> </listitem> - - <listitem> - <para> - The construct -<programlisting> -<replaceable>timestamp</replaceable> AT TIME ZONE '<replaceable>zone</replaceable>' -</programlisting> - where <replaceable>zone</replaceable> can be specified as a - text time zone (e.g., <literal>'PST'</literal>) or as an - interval (e.g., <literal>INTERVAL '-08:00'</literal>). - </para> - </listitem> </itemizedlist> </para> <note> <para> - If an invalid time zone is specified, - the time zone becomes GMT (on most systems anyway). + If an invalid time zone is specified, the time zone becomes + <acronym>UTC</acronym> (on most systems anyway). </para> </note> @@ -2124,8 +2172,9 @@ SELECT * FROM test1 WHERE a; <para> Geometric data types represent two-dimensional spatial objects. <xref linkend="datatype-geo-table"> shows the geometric - types available in PostgreSQL. The most fundamental type, the - point, forms the basis for all of the other types. + types available in <productname>PostgreSQL</productname>. The + most fundamental type, the point, forms the basis for all of the + other types. </para> <table id="datatype-geo-table"> @@ -2746,9 +2795,10 @@ SELECT * FROM test1 WHERE a; <note> <para> - Prior to <productname>PostgreSQL</> 7.2, <type>BIT</type> data was - always silently truncated or zero-padded on the right, with or without an - explicit cast. This was changed to comply with the SQL standard. + Prior to <productname>PostgreSQL</> 7.2, <type>BIT</type> data + was always silently truncated or zero-padded on the right, with + or without an explicit cast. This was changed to comply with the + <acronym>SQL</acronym> standard. </para> </note> @@ -2978,14 +3028,14 @@ SELECT * FROM test; </para> <para> - A third identifier type used by the system is <type>cid</>, or command - identifier. This is the data type of the system columns - <structfield>cmin</> and <structfield>cmax</>. - Command identifiers are also 32-bit quantities. This creates a hard - limit of 2<superscript>32</> (4 billion) SQL commands within a single - transaction. - In practice this limit is not a problem --- note that the limit is on - number of SQL commands, not number of tuples processed. + A third identifier type used by the system is <type>cid</>, or + command identifier. This is the data type of the system columns + <structfield>cmin</> and <structfield>cmax</>. Command + identifiers are also 32-bit quantities. This creates a hard limit + of 2<superscript>32</> (4 billion) <acronym>SQL</acronym> commands + within a single transaction. In practice this limit is not a + problem --- note that the limit is on number of + <acronym>SQL</acronym> commands, not number of tuples processed. </para> <para> @@ -3044,9 +3094,10 @@ SELECT * FROM test; column data type, but it can be used to declare a function's argument or result type. Each of the available pseudo-types is useful in situations where a function's behavior does not - correspond to simply taking or returning a value of a specific SQL - data type. <xref linkend="datatype-pseudotypes-table"> lists the - existing pseudo-types. + correspond to simply taking or returning a value of a specific + <acronym>SQL</acronym> data type. <xref + linkend="datatype-pseudotypes-table"> lists the existing + pseudo-types. </para> <table id="datatype-pseudotypes-table"> @@ -3126,14 +3177,15 @@ SELECT * FROM test; </para> <para> - The <type>internal</> pseudo-type is used to declare functions that are - meant only to be called internally by the database system, and not by - direct invocation in a SQL query. If a function has at least one - <type>internal</>-type argument then it cannot be called from SQL. - To preserve the type safety of this restriction it is important to - follow this coding rule: do not create any function that is declared - to return <type>internal</> unless it has at least one <type>internal</> - argument. + The <type>internal</> pseudo-type is used to declare functions + that are meant only to be called internally by the database + system, and not by direct invocation in a <acronym>SQL</acronym> + query. If a function has at least one <type>internal</>-type + argument then it cannot be called from <acronym>SQL</acronym>. To + preserve the type safety of this restriction it is important to + follow this coding rule: do not create any function that is + declared to return <type>internal</> unless it has at least one + <type>internal</> argument. </para> </sect1> diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 8030497e773..6b1f46984f5 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -1,5 +1,5 @@ <!-- -$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.129.2.1 2002/11/10 12:45:42 petere Exp $ +$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.129.2.2 2002/11/21 23:31:37 tgl Exp $ PostgreSQL documentation --> @@ -3549,9 +3549,14 @@ SUBSTRING('foobar' FROM 'o(.)b') <lineannotation>o</lineannotation> <literal>*</literal>, etc.). For formatting functions, refer to <xref linkend="functions-formatting">. You should be familiar with the background information on date/time data types (see <xref - linkend="datatype-datetime">). The date/time operators described - below behave similarly for types involving time zones as well as - those without. + linkend="datatype-datetime">). + </para> + + <para> + All the functions and operators described below that take time or timestamp + inputs actually come in two variants: one that takes time or timestamp + with time zone, and one that takes time or timestamp without time zone. + For brevity, these variants are not shown separately. </para> <table id="operators-datetime-table"> @@ -3771,7 +3776,7 @@ SUBSTRING('foobar' FROM 'o(.)b') <lineannotation>o</lineannotation> <row> <entry><function>now</function>()</entry> - <entry><type>timestamp</type></entry> + <entry><type>timestamp with time zone</type></entry> <entry>Current date and time (equivalent to <function>current_timestamp</function>); see <xref linkend="functions-datetime-current"> @@ -3898,8 +3903,8 @@ SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40'); <listitem> <para> For <type>date</type> and <type>timestamp</type> values, the - number of seconds since 1970-01-01 00:00:00-00 (Result may be - negative.); for <type>interval</type> values, the total number + number of seconds since 1970-01-01 00:00:00-00 (can be negative); + for <type>interval</type> values, the total number of seconds in the interval </para> @@ -4122,12 +4127,12 @@ SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); <para> The <function>date_part</function> function is modeled on the traditional <productname>Ingres</productname> equivalent to the - <acronym>SQL</acronym>-function <function>extract</function>: + <acronym>SQL</acronym>-standard function <function>extract</function>: <synopsis> date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>) </synopsis> - Note that here the <replaceable>field</replaceable> value needs to - be a string. The valid field values for + Note that here the <replaceable>field</replaceable> parameter needs to + be a string value, not a name. The valid field values for <function>date_part</function> are the same as for <function>extract</function>. </para> @@ -4192,6 +4197,95 @@ SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40'); </para> </sect2> + <sect2 id="functions-datetime-zoneconvert"> + <title><function>AT TIME ZONE</function></title> + + <indexterm> + <primary>timezone</primary> + <secondary>conversion</secondary> + </indexterm> + + <para> + The <function>AT TIME ZONE</function> construct allows conversions + of timestamps to different timezones. + </para> + + <table id="functions-datetime-zoneconvert-table"> + <title>AT TIME ZONE Variants</title> + <tgroup cols="3"> + <thead> + <row> + <entry>Expression</entry> + <entry>Returns</entry> + <entry>Description</entry> + </row> + </thead> + + <tbody> + + <row> + <entry> + <type>timestamp without time zone</type> + <literal>AT TIME ZONE</literal> + <replaceable>zone</> + </entry> + <entry><type>timestamp with time zone</type></entry> + <entry>Convert local time in given timezone to UTC</entry> + </row> + + <row> + <entry> + <type>timestamp with time zone</type> + <literal>AT TIME ZONE</literal> + <replaceable>zone</> + </entry> + <entry><type>timestamp without time zone</type></entry> + <entry>Convert UTC to local time in given timezone</entry> + </row> + + <row> + <entry> + <type>time with time zone</type> + <literal>AT TIME ZONE</literal> + <replaceable>zone</> + </entry> + <entry><type>time with time zone</type></entry> + <entry>Convert local time across timezones</entry> + </row> + + </tbody> + </tgroup> + </table> + + <para> + In these expressions, the desired time <replaceable>zone</> can be + specified either as a text string (e.g., <literal>'PST'</literal>) + or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>). + </para> + + <para> + Examples (supposing that <varname>TimeZone</> is <literal>PST8PDT</>): +<screen> +SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST'; +<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput> + +SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST'; +<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput> +</screen> + The first example takes a zone-less timestamp and interprets it as MST time + (GMT-7) to produce a UTC timestamp, which is then rotated to PST (GMT-8) + for display. The second example takes a timestamp specified in EST + (GMT-5) and converts it to local time in MST (GMT-7). + </para> + + <para> + The function <function>timezone</function>(<replaceable>zone</>, + <replaceable>timestamp</>) is equivalent to the SQL-compliant construct + <replaceable>timestamp</> <literal>AT TIME ZONE</literal> + <replaceable>zone</>. + </para> + </sect2> + <sect2 id="functions-datetime-current"> <title>Current Date/Time</title> @@ -4219,6 +4313,16 @@ LOCALTIMESTAMP LOCALTIME ( <replaceable>precision</replaceable> ) LOCALTIMESTAMP ( <replaceable>precision</replaceable> ) </synopsis> + </para> + + <para> + <function>CURRENT_TIME</function> and + <function>CURRENT_TIMESTAMP</function> deliver values with time zone; + <function>LOCALTIME</function> and + <function>LOCALTIMESTAMP</function> deliver values without time zone. + </para> + + <para> <function>CURRENT_TIME</function>, <function>CURRENT_TIMESTAMP</function>, <function>LOCALTIME</function>, and diff --git a/src/backend/utils/adt/date.c b/src/backend/utils/adt/date.c index 6c35f3ae009..a35353f450d 100644 --- a/src/backend/utils/adt/date.c +++ b/src/backend/utils/adt/date.c @@ -8,7 +8,7 @@ * * * IDENTIFICATION - * $Header: /cvsroot/pgsql/src/backend/utils/adt/date.c,v 1.73 2002/09/21 19:52:41 tgl Exp $ + * $Header: /cvsroot/pgsql/src/backend/utils/adt/date.c,v 1.73.2.1 2002/11/21 23:31:37 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -2013,7 +2013,6 @@ timetz_zone(PG_FUNCTION_ARGS) text *zone = PG_GETARG_TEXT_P(0); TimeTzADT *time = PG_GETARG_TIMETZADT_P(1); TimeTzADT *result; - TimeADT time1; int tz; int type, val; @@ -2040,15 +2039,17 @@ timetz_zone(PG_FUNCTION_ARGS) { tz = val * 60; #ifdef HAVE_INT64_TIMESTAMP - time1 = (time->time - ((time->zone + tz) * INT64CONST(1000000))); - result->time -= ((result->time / time1) * time1); - if (result->time < INT64CONST(0)) + result->time = time->time + ((time->zone - tz) * INT64CONST(1000000)); + while (result->time < INT64CONST(0)) result->time += INT64CONST(86400000000); + while (result->time >= INT64CONST(86400000000)) + result->time -= INT64CONST(86400000000); #else - time1 = (time->time - time->zone + tz); - TMODULO(result->time, time1, 86400e0); - if (result->time < 0) + result->time = time->time + (time->zone - tz); + while (result->time < 0) result->time += 86400; + while (result->time >= 86400) + result->time -= 86400; #endif result->zone = tz; @@ -2087,13 +2088,13 @@ timetz_izone(PG_FUNCTION_ARGS) result = (TimeTzADT *) palloc(sizeof(TimeTzADT)); #ifdef HAVE_INT64_TIMESTAMP - result->time = (time->time + ((time->zone - tz) * INT64CONST(1000000))); + result->time = time->time + ((time->zone - tz) * INT64CONST(1000000)); while (result->time < INT64CONST(0)) result->time += INT64CONST(86400000000); while (result->time >= INT64CONST(86400000000)) result->time -= INT64CONST(86400000000); #else - result->time = (time->time + (time->zone - tz)); + result->time = time->time + (time->zone - tz); while (result->time < 0) result->time += 86400; while (result->time >= 86400)