The EnterpriseDB formatting functions provide a powerful set of tools for converting various data types (date/time, integer, floating point, numeric) to formatted strings and for converting from formatted strings to specific data types. Table 8-19 lists them. These functions all follow a common calling convention: the first argument is the value to be formatted and the second argument is a template that defines the output or input format.
Table 8-19. Formatting Functions
Function | Return Type | Description | Example |
---|---|---|---|
to_char (DATE, VARCHAR) | VARCHAR | convert a value of DATE datatype to VARCHAR datatype | to_char(sysdate, 'HH12:MI:SS') |
to_char (INT, VARCHAR) | VARCHAR | convert INTEGER to VARCHAR | to_char(125, '999') |
to_char (DOUBLE PRECISION,
VARCHAR) | VARCHAR | convert REAL/DOUBLE PRECISION to VARCHAR | to_char(125.8::real, '999D9') |
to_char (NUMERIC, VARCHAR) | VARCHAR | convert >NUMERIC to VARCHAR | to_char(-125.8, '999D99S') |
to_date (VARCHAR, VARCHAR) | DATE | convert VARCHAR to DATE | to_date('05 Dec 2000', 'DD Mon YYYY') |
to_timestamp (VARCHAR, VARCHAR) | TIMESTAMP | convert VARCHAR to TIME STAMP | to_timestamp('05 Dec 2000', 'DD Mon YYYY') |
to_number (VARCHAR, VARCHAR) | NUMERIC | convert VARCHAR to NUMERIC | to_number('12,454.8-', '99G999D9S') |
In an output template string (for to_char
), there are certain patterns that are
recognized and replaced with appropriately-formatted data from the value
to be formatted. Any text that is not a template pattern is simply
copied verbatim. Similarly, in an input template string (for anything but to_char
), template patterns
identify the parts of the input data string to be looked at and the
values to be found there.
Table 8-20 shows the template patterns available for formatting datetime values using the to_char and to_date functions.
Table 8-20. Template Date/Time Format Patterns for the to_char and to_date Functions
Pattern | Description |
---|---|
AD | AD indicator without periods. |
A.D. | AD indicator with periods. |
AM | Meridian indicator without periods. |
A.M. | Meridian indicator with periods. |
BC | BC indicator without periods. |
B.C. | BC indicator with periods. |
CC | One greater than the first two digits of a four-digit year; |
SCC | One greater than the first two digits of a four-digit year; "S" prefixes BC dates with "-" |
D | Day of week (1-7). |
DAY | Name of day, padded with blanks to length of 9 characters. |
DD | Day of month (1-31). |
DDD | Day of year (1-366). |
DY | Abbreviated name of day. |
E | Abbreviated era name (Japanese Imperial, ROC Official, and Thai Buddha calendars). |
EE | Full era name (Japanese Imperial, ROC Official, and Thai Buddha calendars). |
FF [1..9] | Fractional seconds; no radix character is printed (use the X format element to add the radix character). Use the numbers 1 to 9 after FF to specify the number of digits in the fractional second portion of the datetime value returned. If you do not specify a digit, then EnterpriseDB uses the precision specified for the datetime datatype or the datatype's default precision. Example SELECT TO_CHAR(SYSTIMESTAMP, 'SS.FF3') FROM DUAL;
|
HH | Hour of day (1-12). |
HH12 | Hour of day (1-12). |
HH24 | Hour of day (0-23). |
IW | Week of year (1-52 or 1-53) based on the ISO standard. |
IYY IY I | Last 3, 2, or 1 digit(s) of ISO year. |
IYYY | 4-digit year based on the ISO standard. |
J | Julian day; the number of days since January 1, 4712 BC. Number specified with "J" must be integers. |
MI | Minute (0-59). |
MM | Month (01-12; JAN = 01). |
MON | Abbreviated name of month. |
MONTH | Name of month, padded with blanks to length of 9 characters. |
PM | Meridian indicator without periods. |
P.M. | Meridian indicator with periods. |
Q | Quarter of year (1, 2, 3, 4; JAN-MAR = 1). |
RM | Roman numeral month (I-XII; JAN = I). |
RR | Given a year with 2 digits:
|
RRRR | Round year. Accepts either 4-digit or 2-digit input. If 2-digit, provides the same return as RR. If you don't want this functionality, then simply enter the 4-digit year. |
SS | Second (0-59). |
SSSSS | Seconds past midnight (0-86399). |
TZD | Daylight savings information. The TZD value is an abbreviated time zone string with daylight savings information. It must correspond with the region specified in TZR. Examples: PST (for US/Pacific standard time); PDT (for US/Pacific daylight time).
|
TZH | Time zone hour. |
TZM | Time zone minute. |
TZR | Time zone region information. The value must be one of the time zone regions supported in the database. |
WW | Week of year (1-53) where week 1 starts on the first day of the year and continues to the seventh day of the year. |
W | Week of month (1-5) where week 1 starts on the first day of the month and ends on the seventh. |
X | Local radix character. |
Y,YYY | Year with comma in this position. |
YEAR | Year, spelled out |
SYEAR | Year, spelled out; "S" prefixes BC dates with "-". |
YYYY | 4-digit year |
SYYYY | 4-digit year |
YYY YY Y | Last 3, 2, or 1 digit(s) of year. |
Certain modifiers may be applied to any template pattern to alter its behavior. For example, FMMonth is the Month pattern with the FM modifier. Table 8-21 shows the modifier patterns for date/time formatting.
Table 8-21. Template Pattern Modifiers for Date/Time Formatting
Modifier | Description | Example |
---|---|---|
FM prefix | fill mode (suppress padding blanks and zeroes) | FMMonth |
TH suffix | uppercase ordinal number suffix | DDTH |
th suffix | lowercase ordinal number suffix | DDth |
FX prefix | fixed format global option (see usage notes) | FX Month DD Day |
SP suffix | spell mode (not yet implemented) | DDSP |
Usage notes for the date/time formatting:
FM suppresses leading zeroes and trailing blanks that would otherwise be added to make the output of a pattern be fixed-width.
to_timestamp
and to_date
skip multiple blank spaces in the input string if the FX option
is not used. FX must be specified as the first item
in the template. For example
to_timestamp('2000 JUN', 'YYYY MON') is correct, but
to_timestamp('2000 JUN', 'FXYYYY MON') returns an error,
because to_timestamp
expects one space only.
Ordinary text is allowed in to_char
templates and will be output literally. You can put a substring
in double quotes to force it to be interpreted as literal text
even if it contains pattern key words. For example, in
'"Hello Year "YYYY', the YYYY
will be replaced by the year data, but the single Y in Year
will not be.
If you want to have a double quote in the output you must precede it with a backslash, for example '\\"YYYY Month\\"'. (Two backslashes are necessary because the backslash already has a special meaning in a string constant.)
The YYYY conversion from string to TIMESTAMP or DATE has a restriction if you use a year with more than 4 digits. You must use some non-digit character or template after YYYY, otherwise the year is always interpreted as 4 digits. For example (with the year 20000): to_date('200001131', 'YYYYMMDD') will be interpreted as a 4-digit year; instead use a non-digit separator after the year, like to_date('20000-1131', 'YYYY-MMDD') or to_date('20000Nov31', 'YYYYMonDD').
Millisecond (MS) and microsecond (US) values in a conversion from string to TIMESTAMP are used as part of the seconds after the decimal point. For example to_timestamp('12:3', 'SS:MS') is not 3 milliseconds, but 300, because the conversion counts it as 12 + 0.3 seconds. This means for the format SS:MS, the input values 12:3, 12:30, and 12:300 specify the same number of milliseconds. To get three milliseconds, one must use 12:003, which the conversion counts as 12 + 0.003 = 12.003 seconds.
Here is a more complex example: to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US') is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds + 1230 microseconds = 2.021230 seconds.
Table 8-22 shows the template patterns available for formatting numeric values.
Table 8-22. Template Patterns for Numeric Formatting
Pattern | Description |
---|---|
9 | value with the specified number of digits with a leading space if positive or with a leading minus if negative. |
0 | value with leading/trailing zeros |
$ | value with a leading dollar sign |
MI | places a trailing minus sign (-) with a negative value |
D | specifies the location of a decimal point in the returned value |
G | specifies the location of the group separator in the returned value |
L | currency symbol (uses locale) |
D | decimal point (uses locale) |
, (comma) | returns a comma in the specified position. |
. (period) | returns a decimal point, which is a period (.) in the specified position |
Usage notes for the numeric formatting:
A sign formatted using SG, PL, or MI is not anchored to the number; for example, to_char(-12, 'S9999') produces ' -12', but to_char(-12, 'MI9999') produces '- 12'.
9 results in a value with the same number of digits as there are 9s. If a digit is not available it outputs a space.
TH does not convert values less than zero and does not convert fractional numbers.
PL, SG, and TH are EnterpriseDB extensions.
V effectively
multiplies the input values by
10^n, where
n is the number of digits following
V.
to_char
does not support the use of
V combined with a decimal point.
(E.g., 99.9V99 is not allowed.)
Table 8-23 shows some
examples of the use of the to_char
and
to_date
functions.
Table 8-23. to_char
and to_date
function Examples
Expression | Result |
---|---|
to_char(current_timestamp, 'Day, DD HH12:MI:SS') | 'Tuesday , 06 05:39:18' |
to_char(-0.1, '99.99') | ' -.10' |
to_char(-0.1, 'FM9.99') | '-.1' |
to_char(0.1, '0.9') | ' 0.1' |
to_char(12, '9990999.9') | ' 0012.0' |
to_char(12, 'FM9990999.9') | '0012.' |
to_char(485, '999') | ' 485' |
to_char(-485, '999') | '-485' |
to_char(1485, '9,999') | ' 1,485' |
to_char(148.5, '999.999') | ' 148.500' |
to_char(148.5, 'FM999.999') | '148.5' |
to_char(148.5, 'FM999.990') | '148.500' |
to_char(-485, '999S') | '485-' |
to_char(-485, '999MI') | '485-' |
to_char(485, '999MI') | '485 ' |
to_char(485, 'FM999MI') | '485' |
to_char(485, 'L999') | '$ 485 |
to_char(485, 'RN') | ' CDLXXXV' |
to_char(485, 'FMRN') | 'CDLXXXV' |
to_char(5.2, 'FMRN') | 'V' |
to_char(12, '99V999') | ' 12000' |
to_char(12.4, '99V999') | ' 12400' |
to_char(12.45, '99V9') | ' 125' |
to_number(0, '99.9') | '.00' |
to_number(-0.2, '99.9') | '-.20' |