<literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
</entry>
<entry><type>timestamp</type></entry>
- <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc"/>
+ <entry>Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
</entry>
<entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
<entry><literal>2001-02-16 20:00:00</literal></entry>
</row>
+ <row>
+ <entry><literal><function>date_trunc(<type>text</type>, <type>timestamp with time zone</type>, <type>text</type>)</function></literal></entry>
+ <entry><type>timestamp with time zone</type></entry>
+ <entry>Truncate to specified precision in the specified time zone; see <xref linkend="functions-datetime-trunc"/>
+ </entry>
+ <entry><literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal></entry>
+ <entry><literal>2001-02-16 13:00:00+00</literal></entry>
+ </row>
+
<row>
<entry><literal><function>date_trunc(<type>text</type>, <type>interval</type>)</function></literal></entry>
<entry><type>interval</type></entry>
- <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc"/>
+ <entry>Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
</entry>
<entry><literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal></entry>
<entry><literal>2 days 03:00:00</literal></entry>
<para>
<synopsis>
-date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
+date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> [, <replaceable>time_zone</replaceable> ])
</synopsis>
<replaceable>source</replaceable> is a value expression of type
- <type>timestamp</type> or <type>interval</type>.
+ <type>timestamp</type>, <type>timestamp with time zone</type>,
+ or <type>interval</type>.
(Values of type <type>date</type> and
<type>time</type> are cast automatically to <type>timestamp</type> or
<type>interval</type>, respectively.)
<replaceable>field</replaceable> selects to which precision to
- truncate the input value. The return value is of type
- <type>timestamp</type> or <type>interval</type>
- with all fields that are less significant than the
+ truncate the input value. The return value is likewise of type
+ <type>timestamp</type>, <type>timestamp with time zone</type>,
+ or <type>interval</type>,
+ and it has all fields that are less significant than the
selected one set to zero (or one, for day and month).
</para>
</para>
<para>
- Examples:
+ When the input value is of type <type>timestamp with time zone</type>,
+ the truncation is performed with respect to a particular time zone;
+ for example, truncation to <literal>day</literal> produces a value that
+ is midnight in that zone. By default, truncation is done with respect
+ to the current <xref linkend="guc-timezone"/> setting, but the
+ optional <replaceable>time_zone</replaceable> argument can be provided
+ to specify a different time zone. The time zone name can be specified
+ in any of the ways described in <xref linkend="datatype-timezones"/>.
+ </para>
+
+ <para>
+ A time zone cannot be specified when processing <type>timestamp without
+ time zone</type> or <type>interval</type> inputs. These are always
+ taken at face value.
+ </para>
+
+ <para>
+ Examples (assuming the local time zone is <literal>America/New_York</literal>):
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
+
+SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
+<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
+
+SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
+<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
+
+SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
+<lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
</screen>
</para>
</sect2>
PG_RETURN_TIMESTAMP(result);
}
-/* timestamptz_trunc()
- * Truncate timestamp to specified units.
+/*
+ * Common code for timestamptz_trunc() and timestamptz_trunc_zone().
+ *
+ * tzp identifies the zone to truncate with respect to. We assume
+ * infinite timestamps have already been rejected.
*/
-Datum
-timestamptz_trunc(PG_FUNCTION_ARGS)
+static TimestampTz
+timestamptz_trunc_internal(text *units, TimestampTz timestamp, pg_tz *tzp)
{
- text *units = PG_GETARG_TEXT_PP(0);
- TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(1);
TimestampTz result;
int tz;
int type,
struct pg_tm tt,
*tm = &tt;
- if (TIMESTAMP_NOT_FINITE(timestamp))
- PG_RETURN_TIMESTAMPTZ(timestamp);
-
lowunits = downcase_truncate_identifier(VARDATA_ANY(units),
VARSIZE_ANY_EXHDR(units),
false);
if (type == UNITS)
{
- if (timestamp2tm(timestamp, &tz, tm, &fsec, NULL, NULL) != 0)
+ if (timestamp2tm(timestamp, &tz, tm, &fsec, NULL, tzp) != 0)
ereport(ERROR,
(errcode(ERRCODE_DATETIME_VALUE_OUT_OF_RANGE),
errmsg("timestamp out of range")));
}
if (redotz)
- tz = DetermineTimeZoneOffset(tm, session_timezone);
+ tz = DetermineTimeZoneOffset(tm, tzp);
if (tm2timestamp(tm, fsec, &tz, &result) != 0)
ereport(ERROR,
result = 0;
}
+ return result;
+}
+
+/* timestamptz_trunc()
+ * Truncate timestamptz to specified units in session timezone.
+ */
+Datum
+timestamptz_trunc(PG_FUNCTION_ARGS)
+{
+ text *units = PG_GETARG_TEXT_PP(0);
+ TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(1);
+ TimestampTz result;
+
+ if (TIMESTAMP_NOT_FINITE(timestamp))
+ PG_RETURN_TIMESTAMPTZ(timestamp);
+
+ result = timestamptz_trunc_internal(units, timestamp, session_timezone);
+
+ PG_RETURN_TIMESTAMPTZ(result);
+}
+
+/* timestamptz_trunc_zone()
+ * Truncate timestamptz to specified units in specified timezone.
+ */
+Datum
+timestamptz_trunc_zone(PG_FUNCTION_ARGS)
+{
+ text *units = PG_GETARG_TEXT_PP(0);
+ TimestampTz timestamp = PG_GETARG_TIMESTAMPTZ(1);
+ text *zone = PG_GETARG_TEXT_PP(2);
+ TimestampTz result;
+ char tzname[TZ_STRLEN_MAX + 1];
+ char *lowzone;
+ int type,
+ val;
+ pg_tz *tzp;
+
+ /*
+ * timestamptz_zone() doesn't look up the zone for infinite inputs, so we
+ * don't do so here either.
+ */
+ if (TIMESTAMP_NOT_FINITE(timestamp))
+ PG_RETURN_TIMESTAMP(timestamp);
+
+ /*
+ * Look up the requested timezone (see notes in timestamptz_zone()).
+ */
+ text_to_cstring_buffer(zone, tzname, sizeof(tzname));
+
+ /* DecodeTimezoneAbbrev requires lowercase input */
+ lowzone = downcase_truncate_identifier(tzname,
+ strlen(tzname),
+ false);
+
+ type = DecodeTimezoneAbbrev(0, lowzone, &val, &tzp);
+
+ if (type == TZ || type == DTZ)
+ {
+ /* fixed-offset abbreviation, get a pg_tz descriptor for that */
+ tzp = pg_tzset_offset(-val);
+ }
+ else if (type == DYNTZ)
+ {
+ /* dynamic-offset abbreviation, use its referenced timezone */
+ }
+ else
+ {
+ /* try it as a full zone name */
+ tzp = pg_tzset(tzname);
+ if (!tzp)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+ errmsg("time zone \"%s\" not recognized", tzname)));
+ }
+
+ result = timestamptz_trunc_internal(units, timestamp, tzp);
+
PG_RETURN_TIMESTAMPTZ(result);
}
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201811061
+#define CATALOG_VERSION_NO 201811141
#endif
descr => 'truncate timestamp with time zone to specified units',
proname => 'date_trunc', provolatile => 's', prorettype => 'timestamptz',
proargtypes => 'text timestamptz', prosrc => 'timestamptz_trunc' },
+{ oid => '1284',
+ descr => 'truncate timestamp with time zone to specified units in specified time zone',
+ proname => 'date_trunc', provolatile => 's', prorettype => 'timestamptz',
+ proargtypes => 'text timestamptz text', prosrc => 'timestamptz_trunc_zone' },
{ oid => '1218', descr => 'truncate interval to specified units',
proname => 'date_trunc', prorettype => 'interval',
proargtypes => 'text interval', prosrc => 'interval_trunc' },
prorettype => 'timestamptz', proargtypes => '',
prosrc => 'pg_backup_start_time' },
{ oid => '3436', descr => 'promote standby server',
- proname => 'pg_promote', provolatile => 'v',
- prorettype => 'bool', proargtypes => 'bool int4', proargnames => '{wait,wait_seconds}',
+ proname => 'pg_promote', provolatile => 'v', prorettype => 'bool',
+ proargtypes => 'bool int4', proargnames => '{wait,wait_seconds}',
prosrc => 'pg_promote' },
{ oid => '2848', descr => 'switch to new wal file',
proname => 'pg_switch_wal', provolatile => 'v', prorettype => 'pg_lsn',
proallargtypes => '{text,int8,timestamptz}', proargmodes => '{o,o,o}',
proargnames => '{name,size,modification}', prosrc => 'pg_ls_waldir' },
{ oid => '5031', descr => 'list of files in the archive_status directory',
- proname => 'pg_ls_archive_statusdir', procost => '10', prorows => '20', proretset => 't',
- provolatile => 'v', prorettype => 'record', proargtypes => '',
- proallargtypes => '{text,int8,timestamptz}', proargmodes => '{o,o,o}',
- proargnames => '{name,size,modification}', prosrc => 'pg_ls_archive_statusdir' },
+ proname => 'pg_ls_archive_statusdir', procost => '10', prorows => '20',
+ proretset => 't', provolatile => 'v', prorettype => 'record',
+ proargtypes => '', proallargtypes => '{text,int8,timestamptz}',
+ proargmodes => '{o,o,o}', proargnames => '{name,size,modification}',
+ prosrc => 'pg_ls_archive_statusdir' },
{ oid => '5029', descr => 'list files in the pgsql_tmp directory',
proname => 'pg_ls_tmpdir', procost => '10', prorows => '20', proretset => 't',
provolatile => 'v', prorettype => 'record', proargtypes => '',
proallargtypes => '{regclass,regclass,regclass,bool,int4}',
proargmodes => '{i,o,o,o,o}',
proargnames => '{rootrelid,relid,parentrelid,isleaf,level}',
- prosrc => 'pg_partition_tree' }
+ prosrc => 'pg_partition_tree' },
]
| Mon Feb 23 00:00:00 2004 PST
(1 row)
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'Australia/Sydney') as sydney_trunc; -- zone name
+ date_trunc_at_tz | sydney_trunc
+------------------+------------------------------
+ | Fri Feb 16 05:00:00 2001 PST
+(1 row)
+
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'GMT') as gmt_trunc; -- fixed-offset abbreviation
+ date_trunc_at_tz | gmt_trunc
+------------------+------------------------------
+ | Thu Feb 15 16:00:00 2001 PST
+(1 row)
+
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'VET') as vet_trunc; -- variable-offset abbreviation
+ date_trunc_at_tz | vet_trunc
+------------------+------------------------------
+ | Thu Feb 15 20:00:00 2001 PST
+(1 row)
+
-- Test casting within a BETWEEN qualifier
SELECT '' AS "54", d1 - timestamp with time zone '1997-01-02' AS diff
FROM TIMESTAMPTZ_TBL
SELECT '' AS date_trunc_week, date_trunc( 'week', timestamp with time zone '2004-02-29 15:44:17.71393' ) AS week_trunc;
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'Australia/Sydney') as sydney_trunc; -- zone name
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'GMT') as gmt_trunc; -- fixed-offset abbreviation
+SELECT '' AS date_trunc_at_tz, date_trunc('day', timestamp with time zone '2001-02-16 20:38:40+00', 'VET') as vet_trunc; -- variable-offset abbreviation
+
-- Test casting within a BETWEEN qualifier
SELECT '' AS "54", d1 - timestamp with time zone '1997-01-02' AS diff
FROM TIMESTAMPTZ_TBL