Commit 4ebb0cf9 authored by Bruce Momjian's avatar Bruce Momjian

Add two new format fields for use with to_char(), to_date() and

to_timestamp():
    - ID for day-of-week
    - IDDD for day-of-year

This makes it possible to convert ISO week dates to and from text
fully represented in either week ('IYYY-IW-ID') or day-of-year
('IYYY-IDDD') format.

I have also added an 'isoyear' field for use with extract / date_part.

Brendan Jurd
parent c7b08050
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.358 2007/02/14 18:46:08 petere Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.359 2007/02/16 03:39:44 momjian Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
......@@ -4539,7 +4539,7 @@ SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
</row>
<row>
<entry><literal>I</literal></entry>
<entry>last digits of ISO year</entry>
<entry>last digit of ISO year</entry>
</row>
<row>
<entry><literal>BC</literal> or <literal>B.C.</literal> or
......@@ -4607,6 +4607,10 @@ SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
<entry><literal>DDD</literal></entry>
<entry>day of year (001-366)</entry>
</row>
<row>
<entry><literal>IDDD</literal></entry>
<entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
</row>
<row>
<entry><literal>DD</literal></entry>
<entry>day of month (01-31)</entry>
......@@ -4615,6 +4619,10 @@ SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
<entry><literal>D</literal></entry>
<entry>day of week (1-7; Sunday is 1)</entry>
</row>
<row>
<entry><literal>ID</literal></entry>
<entry>ISO day of week (1-7; Monday is 1)</entry>
</row>
<row>
<entry><literal>W</literal></entry>
<entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
......@@ -4625,7 +4633,7 @@ SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
</row>
<row>
<entry><literal>IW</literal></entry>
<entry>ISO week number of year (The first Thursday of the new year is in week 1.)</entry>
<entry>ISO week number of year (1 - 53; the first Thursday of the new year is in week 1.)</entry>
</row>
<row>
<entry><literal>CC</literal></entry>
......@@ -4791,6 +4799,27 @@ SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
</para>
</listitem>
<listitem>
<para>
An ISO week date (as distinct from a Gregorian date) can be specified to <function>to_timestamp</function> and <function>to_date</function> in one of two ways:
<itemizedlist>
<listitem>
<para>
Year, week and weekday, for example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal> returns the date <literal>2006-10-19</literal>. If you omit the weekday it is assumed to be 1 (Monday).
</para>
</listitem>
<listitem>
<para>
Year and day of year, for example <literal>to_date('2006-291', 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
</para>
</listitem>
</itemizedlist>
</para>
<para>
Attempting to construct a date using a mixture of ISO week and Gregorian date fields is nonsensical, and could yield unexpected results. In the context of an ISO year, the concept of a 'month' or 'day of month' has no meaning. In the context of a Gregorian year, the ISO week has no meaning. Users should take care to keep Gregorian and ISO date specifications separate.
</para>
</listitem>
<listitem>
<para>
Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
......@@ -5776,6 +5805,29 @@ SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
</listitem>
</varlistentry>
<varlistentry>
<term><literal>isoyear</literal></term>
<listitem>
<para>
The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals).
</para>
<screen>
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
<lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
<lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
</screen>
<para>
Each <acronym>ISO</acronym> year begins with the Monday of the week containing the 4th of January, so in early January or late December the <acronym>ISO</acronym> year may be different from the Gregorian year. See the <literal>week</literal> field for more information.
</para>
<para>
This field is not available in PostgreSQL releases prior to 8.3.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>microseconds</literal></term>
<listitem>
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/adt/date.c,v 1.127 2007/01/05 22:19:40 momjian Exp $
* $PostgreSQL: pgsql/src/backend/utils/adt/date.c,v 1.128 2007/02/16 03:39:44 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1748,6 +1748,7 @@ time_part(PG_FUNCTION_ARGS)
case DTK_DECADE:
case DTK_CENTURY:
case DTK_MILLENNIUM:
case DTK_ISOYEAR:
default:
ereport(ERROR,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/adt/datetime.c,v 1.175 2007/01/05 22:19:40 momjian Exp $
* $PostgreSQL: pgsql/src/backend/utils/adt/datetime.c,v 1.176 2007/02/16 03:39:45 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -125,6 +125,7 @@ static const datetkn datetktbl[] = {
{"h", UNITS, DTK_HOUR}, /* "hour" */
{LATE, RESERV, DTK_LATE}, /* "infinity" reserved for "late time" */
{INVALID, RESERV, DTK_INVALID}, /* "invalid" reserved for bad time */
{"isoyear", UNITS, DTK_ISOYEAR}, /* year in terms of the ISO week date */
{"j", UNITS, DTK_JULIAN},
{"jan", MONTH, 1},
{"january", MONTH, 1},
......
This diff is collapsed.
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.171 2007/01/05 22:19:42 momjian Exp $
* $PostgreSQL: pgsql/src/backend/utils/adt/timestamp.c,v 1.172 2007/02/16 03:39:45 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -3749,32 +3749,57 @@ interval_trunc(PG_FUNCTION_ARGS)
PG_RETURN_INTERVAL_P(result);
}
/* isoweek2date()
* Convert ISO week of year number to date.
* The year field must be specified with the ISO year!
* karel 2000/08/07
/* isoweek2j()
*
* Return the Julian day which corresponds to the first day (Monday) of the given ISO 8601 year and week.
* Julian days are used to convert between ISO week dates and Gregorian dates.
*/
void
isoweek2date(int woy, int *year, int *mon, int *mday)
int
isoweek2j(int year, int week)
{
int day0,
day4,
dayn;
day4;
if (!*year)
if (!year)
ereport(ERROR,
(errcode(ERRCODE_INVALID_PARAMETER_VALUE),
errmsg("cannot calculate week number without year information")));
/* fourth day of current year */
day4 = date2j(*year, 1, 4);
day4 = date2j(year, 1, 4);
/* day0 == offset to first day of week (Monday) */
day0 = j2day(day4 - 1);
dayn = ((woy - 1) * 7) + (day4 - day0);
return ((week - 1) * 7) + (day4 - day0);
}
/* isoweek2date()
* Convert ISO week of year number to date.
* The year field must be specified with the ISO year!
* karel 2000/08/07
*/
void
isoweek2date(int woy, int *year, int *mon, int *mday)
{
j2date(isoweek2j(*year, woy), year, mon, mday);
}
/* isoweekdate2date()
*
* Convert an ISO 8601 week date (ISO year, ISO week and day of week) into a Gregorian date.
* Populates year, mon, and mday with the correct Gregorian values.
* year must be passed in as the ISO year.
*/
void
isoweekdate2date(int isoweek, int isowday, int *year, int *mon, int *mday)
{
int jday;
jday = isoweek2j(*year, isoweek);
jday += isowday - 1;
j2date(dayn, year, mon, mday);
j2date(jday, year, mon, mday);
}
/* date2isoweek()
......@@ -3887,6 +3912,17 @@ date2isoyear(int year, int mon, int mday)
}
/* date2isoyearday()
*
* Returns the ISO 8601 day-of-year, given a Gregorian year, month and day.
* Possible return values are 1 through 371 (364 in non-leap years).
*/
int
date2isoyearday(int year, int mon, int mday)
{
return date2j(year, mon, mday) - isoweek2j(date2isoyear(year, mon, mday), 1) + 1;
}
/* timestamp_part()
* Extract specified field from timestamp.
*/
......@@ -4029,6 +4065,10 @@ timestamp_part(PG_FUNCTION_ARGS)
#endif
break;
case DTK_ISOYEAR:
result = date2isoyear(tm->tm_year, tm->tm_mon, tm->tm_mday);
break;
case DTK_TZ:
case DTK_TZ_MINUTE:
case DTK_TZ_HOUR:
......@@ -4256,6 +4296,10 @@ timestamptz_part(PG_FUNCTION_ARGS)
#endif
break;
case DTK_ISOYEAR:
result = date2isoyear(tm->tm_year, tm->tm_mon, tm->tm_mday);
break;
default:
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
......
......@@ -9,7 +9,7 @@
* Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/utils/datetime.h,v 1.63 2007/01/05 22:19:59 momjian Exp $
* $PostgreSQL: pgsql/src/include/utils/datetime.h,v 1.64 2007/02/16 03:39:45 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -165,6 +165,7 @@
#define DTK_DOY 33
#define DTK_TZ_HOUR 34
#define DTK_TZ_MINUTE 35
#define DTK_ISOYEAR 36
/*
......
......@@ -6,7 +6,7 @@
* Portions Copyright (c) 1996-2007, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/utils/timestamp.h,v 1.66 2007/01/05 22:19:59 momjian Exp $
* $PostgreSQL: pgsql/src/include/utils/timestamp.h,v 1.67 2007/02/16 03:39:45 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -331,8 +331,11 @@ extern int timestamp_cmp_internal(Timestamp dt1, Timestamp dt2);
/* timestamp comparison works for timestamptz also */
#define timestamptz_cmp_internal(dt1,dt2) timestamp_cmp_internal(dt1, dt2)
extern void isoweek2date(int woy, int *year, int *mon, int *mday);
extern int isoweek2j(int year, int week);
extern void isoweek2date(int woy, int *year, int *mon, int *mday);
extern void isoweekdate2date(int isoweek, int isowday, int *year, int *mon, int *mday);
extern int date2isoweek(int year, int mon, int mday);
extern int date2isoyear(int year, int mon, int mday);
extern int date2isoyearday(int year, int mon, int mday);
#endif /* TIMESTAMP_H */
/* $PostgreSQL: pgsql/src/interfaces/ecpg/pgtypeslib/dt.h,v 1.34 2006/03/11 04:38:39 momjian Exp $ */
/* $PostgreSQL: pgsql/src/interfaces/ecpg/pgtypeslib/dt.h,v 1.35 2007/02/16 03:39:45 momjian Exp $ */
#ifndef DT_H
#define DT_H
......@@ -157,6 +157,7 @@ typedef double fsec_t;
#define DTK_DOY 33
#define DTK_TZ_HOUR 34
#define DTK_TZ_MINUTE 35
#define DTK_ISOYEAR 36
/*
......
This diff is collapsed.
This diff is collapsed.
......@@ -171,6 +171,11 @@ SELECT '' AS "54", d1 as "timestamp",
date_part( 'usec', d1) AS usec
FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
SELECT '' AS "54", d1 as "timestamp",
date_part( 'isoyear', d1) AS isoyear, date_part( 'week', d1) AS week,
date_part( 'dow', d1) AS dow
FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
-- TO_CHAR()
SELECT '' AS to_char_1, to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
FROM TIMESTAMP_TBL;
......@@ -199,6 +204,12 @@ SELECT '' AS to_char_8, to_char(d1, 'YYYYTH YYYYth Jth')
SELECT '' AS to_char_9, to_char(d1, 'YYYY A.D. YYYY a.d. YYYY bc HH:MI:SS P.M. HH:MI:SS p.m. HH:MI:SS pm')
FROM TIMESTAMP_TBL;
SELECT '' AS to_char_10, to_char(d1, 'IYYY IYY IY I IW IDDD ID')
FROM TIMESTAMP_TBL;
SELECT '' AS to_char_11, to_char(d1, 'FMIYYY FMIYY FMIY FMI FMIW FMIDDD FMID')
FROM TIMESTAMP_TBL;
-- TO_TIMESTAMP()
SELECT '' AS to_timestamp_1, to_timestamp('0097/Feb/16 --> 08:14:30', 'YYYY/Mon/DD --> HH:MI:SS');
......@@ -230,4 +241,18 @@ SELECT '' AS to_timestamp_13, to_timestamp('95-1116', 'YY-MMDD');
SELECT '' AS to_timestamp_14, to_timestamp('995-1116', 'YYY-MMDD');
SELECT '' AS to_timestamp_15, to_timestamp('2005426', 'YYYYWWD');
SELECT '' AS to_timestamp_16, to_timestamp('2005300', 'YYYYDDD');
SELECT '' AS to_timestamp_17, to_timestamp('2005527', 'IYYYIWID');
SELECT '' AS to_timestamp_18, to_timestamp('005527', 'IYYIWID');
SELECT '' AS to_timestamp_19, to_timestamp('05527', 'IYIWID');
SELECT '' AS to_timestamp_20, to_timestamp('5527', 'IIWID');
SELECT '' AS to_timestamp_21, to_timestamp('2005364', 'IYYYIDDD');
SET DateStyle TO DEFAULT;
......@@ -169,6 +169,11 @@ SELECT '' AS "54", d1 as timestamptz,
date_part( 'usec', d1) AS usec
FROM TIMESTAMPTZ_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
SELECT '' AS "54", d1 as "timestamp",
date_part( 'isoyear', d1) AS isoyear, date_part( 'week', d1) AS week,
date_part( 'dow', d1) AS dow
FROM TIMESTAMP_TBL WHERE d1 BETWEEN '1902-01-01' AND '2038-01-01';
-- TO_CHAR()
SELECT '' AS to_char_1, to_char(d1, 'DAY Day day DY Dy dy MONTH Month month RM MON Mon mon')
FROM TIMESTAMPTZ_TBL;
......@@ -197,8 +202,11 @@ SELECT '' AS to_char_8, to_char(d1, 'YYYYTH YYYYth Jth')
SELECT '' AS to_char_9, to_char(d1, 'YYYY A.D. YYYY a.d. YYYY bc HH:MI:SS P.M. HH:MI:SS p.m. HH:MI:SS pm')
FROM TIMESTAMPTZ_TBL;
SELECT '' AS to_char_10, to_char(d1, 'YYYY WW IYYY IYY IY I IW')
FROM TIMESTAMPTZ_TBL;
SELECT '' AS to_char_10, to_char(d1, 'IYYY IYY IY I IW IDDD ID')
FROM TIMESTAMP_TBL;
SELECT '' AS to_char_11, to_char(d1, 'FMIYYY FMIYY FMIY FMI FMIW FMIDDD FMID')
FROM TIMESTAMP_TBL;
-- TO_TIMESTAMP()
SELECT '' AS to_timestamp_1, to_timestamp('0097/Feb/16 --> 08:14:30', 'YYYY/Mon/DD --> HH:MI:SS');
......@@ -231,9 +239,18 @@ SELECT '' AS to_timestamp_13, to_timestamp('95-1116', 'YY-MMDD');
SELECT '' AS to_timestamp_14, to_timestamp('995-1116', 'YYY-MMDD');
SELECT '' AS to_timestamp_15, to_timestamp('200401', 'IYYYIW');
SELECT '' AS to_timestamp_15, to_timestamp('2005426', 'YYYYWWD');
SELECT '' AS to_timestamp_16, to_timestamp('2005300', 'YYYYDDD');
SELECT '' AS to_timestamp_17, to_timestamp('2005527', 'IYYYIWID');
SELECT '' AS to_timestamp_18, to_timestamp('005527', 'IYYIWID');
SELECT '' AS to_timestamp_19, to_timestamp('05527', 'IYIWID');
SELECT '' AS to_timestamp_16, to_timestamp('200401', 'YYYYWW');
SELECT '' AS to_timestamp_20, to_timestamp('5527', 'IIWID');
SELECT '' AS to_timestamp_21, to_timestamp('2005364', 'IYYYIDDD');
SET DateStyle TO DEFAULT;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment