EnterpriseDB supports the date
and time types shown in Table 7-7.
Table 7-7. Date/Time Types
Name | Storage Size | Description | Low Value | High Value | Resolution |
---|
DATE | 4 bytes | dates only | 4713 BC | 5874897 AD | 1 day |
TIMESTAMP [ (p) ] | 8 bytes | date and time | 4713 BC | 5874897 AD | 1 microsecond |
When DATE appears as the data type of a column in the data definition
language (DDL) commands, CREATE TABLE or ALTER
TABLE, it is translated to TIMESTAMP(0) at the time the table
definition is stored in the data base if the configuration parameter
edb_redwood_date is set to true. Thus, a time component
will also be stored in the column along with the date.
If edb_redwood_date is set to false, the column's data type in a
CREATE TABLE or ALTER TABLE command remains as
DATE and is stored as such in the database. Only a date
without a time component will be stored in the column.
Regardless of the setting of edb_redwood_date, when DATE
appears as a data type in any other context such as the data type of a
variable in an SPL declaration section, or the data type
of a formal parameter in an SPL procedure or an
SPL function, or the return type of an SPL
function, it is always translated to TIMESTAMP(0) and thus can
handle a time component if present.
TIMESTAMP accepts an optional precision value
p which specifies the number of
fractional digits retained in the seconds field. The allowed
range of p is from 0 to 6 with
the default being 6.
Note: When TIMESTAMP values are stored as double precision floating-point
numbers (currently the default), the effective limit of precision
may be less than 6. TIMESTAMP values are stored as seconds
before or after midnight 2000-01-01. Microsecond precision is achieved for
dates within a few years of 2000-01-01, but the precision degrades for
dates further away. When TIMESTAMP values are stored as
eight-byte integers (a compile-time option), microsecond precision
is available over the full range of values. However eight-byte integer
timestamps have a more limited range of dates than shown above:
from 4713 BC up to 294276 AD.
DATETIME and SMALLDATETIME may also be used
as synonyms for TIMESTAMP.
Date and time input is accepted in ISO 8601,
SQL-compatible format.
Remember that any date or time literal input needs to be enclosed
in single quotes, like text strings.
SQL requires the following syntax
type [ (p) ] 'value'
where p in the optional precision
specification is an integer corresponding to the number of
fractional digits in the seconds field. Precision can be
specified for the TIMESTAMP type.
The allowed values are mentioned above. If no precision is specified
in a constant specification, it defaults to the precision of the
literal value.
For some formats, ordering of month, day, and year in date input is
ambiguous and there is support for specifying the expected
ordering of these fields. Set the DateStyle parameter
to MDY to select month-day-year interpretation,
DMY to select day-month-year interpretation, or
YMD to select year-month-day interpretation.
Table 7-8 shows some possible
input formats for dates.
Table 7-8. Date Input
Example | Description |
---|
January 8, 1999 | unambiguous in any datestyle input mode |
1999-01-08 | ISO 8601; January 8 in any mode
(recommended format) |
1/8/1999 | January 8 in MDY mode;
August 1 in DMY mode |
1/18/1999 | January 18 in MDY mode;
rejected in other modes |
01/02/03 | January 2, 2003 in MDY mode;
February 1, 2003 in DMY mode;
February 3, 2001 in YMD mode
|
1999-Jan-08 | January 8 in any mode |
Jan-08-1999 | January 8 in any mode |
08-Jan-1999 | January 8 in any mode |
99-Jan-08 | January 8 in YMD mode, else error |
08-Jan-99 | January 8, except error in YMD mode |
Jan-08-99 | January 8, except error in YMD mode |
19990108 | ISO 8601; January 8, 1999 in any mode |
990108 | ISO 8601; January 8, 1999 in any mode |
1999.008 | year and day of year |
J2451187 | Julian day |
January 8, 99 BC | year 99 before the Common Era |
The date values can be assigned to a DATE
or TIMESTAMP column or variable. The hour,
minute, and seconds fields will be set to zero if the
date value is not appended with a time value, examples
of which are shown in
Table 7-9.
The following table gives examples of time input values
that can be used in conjunction with the date values shown in
Table 7-8.
Table 7-9. Time Input
Example | Description |
---|
04:05:06.789 | ISO 8601 |
04:05:06 | ISO 8601 |
04:05 | ISO 8601 |
040506 | ISO 8601 |
04:05 AM | same as 04:05; AM does not affect value |
04:05 PM | same as 16:05; input hour must be <= 12 |
Valid input for the time stamp types consists of a concatenation
of a date and a time. The date portion of the time stamp can be
formatted according to any of the examples shown in
Table 7-8. The time portion
of the time stamp can be formatted according to any of examples
shown in Table 7-9.
The following is an example of a time stamp
which follows the ISO 8601 standard.
1999-01-08 04:05:06
In addition, the wide-spread format
January 8 04:05:06 1999
is supported.
EnterpriseDB supports several
special date/time input values for convenience, as shown in Table 7-10. The values
infinity and -infinity
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.
All of these values are treated as normal constants and need to be
written in single quotes.
Table 7-10. Special Date/Time Inputs
Input String | Valid Types | Description |
---|
epoch | DATE, TIMESTAMP | 1970-01-01 00:00:00 (Unix system time zero) |
infinity | TIMESTAMP | later than all other time stamps |
-infinity | TIMESTAMP | earlier than all other time stamps |
now | DATE, TIMESTAMP | current transaction's start time |
today | DATE, TIMESTAMP | midnight today |
tomorrow | DATE, TIMESTAMP | midnight tomorrow |
yesterday | DATE, TIMESTAMP | midnight yesterday |
The following functions can be used to obtain the current date/time
value for the corresponding data type:
CURRENT_DATE, SYSDATE, and
CURRENT_TIMESTAMP.
The latter accepts an optional subsecond precision specification.
(See also Section 8.8.4.)
The output format of the date/time types can be set to one of the five
styles Redwood, ISO 8601,
SQL (Ingres), traditional POSTGRES, and
German, using the command SET datestyle. The default
is the Redwood format. (The
SQL standard requires the use of the ISO 8601
format. The name of the "SQL" output format is a
historical accident.) Table 7-11 shows examples of each
output style.
Table 7-11. Date/Time Output Styles
Style Specification | Description | Example |
---|
Redwood | redwood style | 31-DEC-05 07:37:16 |
ISO | ISO 8601/SQL standard | 1997-12-17 07:37:16 |
SQL | traditional style | 12/17/1997 07:37:16.00 |
POSTGRES | original style | Wed Dec 17 07:37:16 1997 |
German | regional style | 17.12.1997 07:37:16.00 |
In the SQL and POSTGRES styles, day appears before
month if DMY field ordering has been specified, otherwise month appears
before day.
(See Section 7.4.1
for how this setting also affects interpretation of input values.)
Table 7-12 shows an
example.
Table 7-12. Date Order Conventions
datestyle Setting | Input Ordering | Example Output |
---|
SQL, DMY | day/month/year | 17/12/1997 15:37:16.00 |
SQL, MDY | month/day/year | 12/17/1997 07:37:16.00 |
Postgres, DMY | day/month/year | Wed 17 Dec 07:37:16 1997 |
The date/time styles can be selected by the user using the
SET datestyle command, the DateStyle parameter in the
postgresql.conf configuration file, or the
PGDATESTYLE environment variable on the server or
client. The formatting function to_char
(see Section 8.7) is also available as
a more flexible way to format the date/time output.
For example, if our date/time style is
"redwood" and we wish to change it to "POSTGRES", we
would issue the following SQL command via edb-psql.
SET datestyle TO POSTGRES;
Unlike the other datestyles, the redwood datestyle has two settings:
redwood, hide_time
redwood, show_time
The hide_time setting suppresses the display of the time component of
a TIMESTAMP(0) column or variable. The show_time setting displays the
time component of a TIMESTAMP(0) column or variable.
Please recall that the configuration parameter edb_redwood_date = true causes all DATE data types in DDL statements,
to be translated to TIMESTAMP(0) which means that both date and time are stored. However, when edb_redwood_date = false, all
DATE data types in DDL statements consist of a date without the time.
For all other variables and parameters such as in the declaration section of
procedures, functions, and triggers and in their signature declaration,
DATE is always translated to TIMESTAMP(0).
The hide_time and show_time settings control whether or not you want to see
the time component of these columns or variables for which you may consider only
the date portion meaningful in your particular application. Of course you may
always use the to_char function to explicitly control the display appearance.
The following tables show the output displayed to the user with different redwood and non-redwood date style settings.
Table 7-13. edb_redwood_date set to true
Datestyle setting | Data Type | Column Display Format | Variable Display Format |
---|
redwood, hide_time | DATE | dd-MON-yy | dd-MON-yy |
redwood, hide_time | TIMESTAMP(0) | dd-MON-yy | dd-MON-yy |
redwood, show_time | DATE | dd-MON-yy hh24:mi:ss | dd-MON-yy hh24:mi:ss |
redwood, show_time | TIMESTAMP(0) | dd-MON-yy hh24:mi:ss | dd-MON-yy hh24:mi:ss |
Non-redwood, e.g.ISO | DATE | yyyy-mm-dd hh24:mi:ss | yyyy-mm-dd hh24:mi:ss |
Non-redwood, e.g.ISO | TIMESTAMP(0) | yyyy-mm-dd hh24:mi:ss | yyyy-mm-dd hh24:mi:ss |
Table 7-14. edb_redwood_date set to false
Datestyle setting | Data Type | Column Display Format | Variable Display Format |
---|
redwood, hide_time | DATE | dd-MON-yy | dd-MON-yy |
redwood, hide_time | TIMESTAMP(0) | dd-MON-yy | dd-MON-yy |
redwood, show_time | DATE | dd-MON-yy | dd-MON-yy hh24:mi:ss |
redwood, show_time | TIMESTAMP(0) | dd-MON-yy hh24:mi:ss | dd-MON-yy hh24:mi:ss |
Non-redwood, e.g.ISO | DATE | yyyy-mm-dd | yyyy-mm-dd hh24:mi:ss |
Non-redwood, e.g.ISO | TIMESTAMP(0) | yyyy-mm-dd hh24:mi:ss | yyyy-mm-dd hh24:mi:ss |
EnterpriseDB uses Julian dates
for all date/time calculations. They have the nice property of correctly
predicting/calculating any date more recent than 4713 BC
to far into the future, using the assumption that the length of the
year is 365.2425 days.