PostgreSQL
9.8. Data Type Formatting Functions
The PostgreSQL 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 9.23 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 9.23. Formatting Functions
Function | Return Type | Description | Example |
---|---|---|---|
|
|
convert time stamp to string |
|
|
|
convert interval to string |
|
|
|
convert integer to string |
|
|
|
convert real/double precision to string |
|
|
|
convert numeric to string |
|
|
|
convert string to date |
|
|
|
convert string to numeric |
|
|
|
convert string to time stamp |
|
+
Note
There is also a single-argument to_timestamp
function; see Table 9.30.
Tip
to_timestamp
and to_date
exist to handle input formats that cannot be converted by simple casting. For most standard date/time formats, simply casting the source string to the required data type works, and is much easier. Similarly, to_number
is unnecessary for standard numeric representations.
In a to_char
output template string, there are certain patterns that are recognized and replaced with appropriately-formatted data based on the given value. Any text that is not a template pattern is simply copied verbatim. Similarly, in an input template string (for the other functions), template patterns identify the values to be supplied by the input data string.
Table 9.24 shows the template patterns available for formatting date and time values.
Table 9.24. Template Patterns for Date/Time Formatting
Pattern | Description |
---|---|
|
hour of day (01-12) |
|
hour of day (01-12) |
|
hour of day (00-23) |
|
minute (00-59) |
|
second (00-59) |
|
millisecond (000-999) |
|
microsecond (000000-999999) |
|
seconds past midnight (0-86399) |
|
meridiem indicator (without periods) |
|
meridiem indicator (with periods) |
|
year (4 or more digits) with comma |
|
year (4 or more digits) |
|
last 3 digits of year |
|
last 2 digits of year |
|
last digit of year |
|
ISO 8601 week-numbering year (4 or more digits) |
|
last 3 digits of ISO 8601 week-numbering year |
|
last 2 digits of ISO 8601 week-numbering year |
|
last digit of ISO 8601 week-numbering year |
|
era indicator (without periods) |
|
era indicator (with periods) |
|
full upper case month name (blank-padded to 9 chars) |
|
full capitalized month name (blank-padded to 9 chars) |
|
full lower case month name (blank-padded to 9 chars) |
|
abbreviated upper case month name (3 chars in English, localized lengths vary) |
|
abbreviated capitalized month name (3 chars in English, localized lengths vary) |
|
abbreviated lower case month name (3 chars in English, localized lengths vary) |
|
month number (01-12) |
|
full upper case day name (blank-padded to 9 chars) |
|
full capitalized day name (blank-padded to 9 chars) |
|
full lower case day name (blank-padded to 9 chars) |
|
abbreviated upper case day name (3 chars in English, localized lengths vary) |
|
abbreviated capitalized day name (3 chars in English, localized lengths vary) |
|
abbreviated lower case day name (3 chars in English, localized lengths vary) |
|
day of year (001-366) |
|
day of ISO 8601 week-numbering year (001-371; day 1 of the year is Monday of the first ISO week) |
|
day of month (01-31) |
|
day of the week, Sunday ( |
|
ISO 8601 day of the week, Monday ( |
|
week of month (1-5) (the first week starts on the first day of the month) |
|
week number of year (1-53) (the first week starts on the first day of the year) |
|
week number of ISO 8601 week-numbering year (01-53; the first Thursday of the year is in week 1) |
|
century (2 digits) (the twenty-first century starts on 2001-01-01) |
|
Julian Date (integer days since November 24, 4714 BC at local midnight; see Section B.7) |
|
quarter |
|
month in upper case Roman numerals (I-XII; I=January) |
|
month in lower case Roman numerals (i-xii; i=January) |
|
upper case time-zone abbreviation (only supported in |
|
lower case time-zone abbreviation (only supported in |
|
time-zone offset from UTC (only supported in |
+
Modifiers can be applied to any template pattern to alter its behavior. For example, FMMonth
is the Month
pattern with the FM
modifier. Table 9.25 shows the modifier patterns for date/time formatting.
Table 9.25. Template Pattern Modifiers for Date/Time Formatting
Modifier | Description | Example |
---|---|---|
|
fill mode (suppress leading zeroes and padding blanks) |
|
|
upper case ordinal number suffix |
|
|
lower case ordinal number suffix |
|
|
fixed format global option (see usage notes) |
|
|
translation mode (print localized day and month names based on lc_time) |
|
|
spell mode (not implemented) |
|
+
Usage notes for 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. In PostgreSQL,FM
modifies only the next specification, while in OracleFM
affects all subsequent specifications, and repeatedFM
modifiers toggle fill mode on and off. -
TM
does not include trailing blanks.to_timestamp
andto_date
ignore theTM
modifier. -
to_timestamp
andto_date
skip multiple blank spaces in the input string unless theFX
option is used. For example,to_timestamp('2000 JUN', 'YYYY MON')
works, butto_timestamp('2000 JUN', 'FXYYYY MON')
returns an error becauseto_timestamp
expects one space only.FX
must be specified as the first item in the template. -
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'
, theYYYY
will be replaced by the year data, but the singleY
inYear
will not be. Into_date
,to_number
, andto_timestamp
, double-quoted strings skip the number of input characters contained in the string, e.g.,"XX"
skips two input characters. -
If you want to have a double quote in the output you must precede it with a backslash, for example
'\"YYYY Month\"'
. -
In
to_timestamp
andto_date
, if the year format specification is less than four digits, e.g.,YYY
, and the supplied year is less than four digits, the year will be adjusted to be nearest to the year 2020, e.g.,95
becomes 1995. -
In
to_timestamp
andto_date
, negative years are treated as signifying BC. If you write both a negative year and an explicitBC
field, you get AD again. An input of year zero is treated as 1 BC. -
In
to_timestamp
andto_date
, theYYYY
conversion has a restriction when processing years with more than 4 digits. You must use some non-digit character or template afterYYYY
, 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, liketo_date('20000-1131', 'YYYY-MMDD')
orto_date('20000Nov31', 'YYYYMonDD')
. -
In
to_timestamp
andto_date
, theCC
(century) field is accepted but ignored if there is aYYY
,YYYY
orY,YYY
field. IfCC
is used withYY
orY
then the result is computed as that year in the specified century. If the century is specified but the year is not, the first year of the century is assumed. -
In
to_timestamp
andto_date
, weekday names or numbers (DAY
,D
, and related field types) are accepted but are ignored for purposes of computing the result. The same is true for quarter (Q
) fields. -
In
to_timestamp
andto_date
, an ISO 8601 week-numbering date (as distinct from a Gregorian date) can be specified in one of two ways:-
Year, week number, and weekday: for example
to_date('2006-42-4', 'IYYY-IW-ID')
returns the date2006-10-19
. If you omit the weekday it is assumed to be 1 (Monday). -
Year and day of year: for example
to_date('2006-291', 'IYYY-IDDD')
also returns2006-10-19
.Attempting to enter a date using a mixture of ISO 8601 week-numbering fields and Gregorian date fields is nonsensical, and will cause an error. In the context of an ISO 8601 week-numbering year, the concept of a “[.quote]#month”# or “[.quote]#day of month”# has no meaning. In the context of a Gregorian year, the ISO week has no meaning.
==== Caution
While
to_date
will reject a mixture of Gregorian and ISO week-numbering date fields,to_char
will not, since output format specifications likeYYYY-MM-DD (IYYY-IDDD)
can be useful. But avoid writing something likeIYYY-MM-DD
; that would yield surprising results near the start of the year. (See Section 9.9.1 for more information.)
-
-
In
to_timestamp
, millisecond (MS
) or microsecond (US
) fields are used as the seconds digits after the decimal point. For exampleto_timestamp('12.3', 'SS.MS')
is not 3 milliseconds, but 300, because the conversion treats it as 12 + 0.3 seconds. So, for the formatSS.MS
, the input values12.3
,12.30
, and12.300
specify the same number of milliseconds. To get three milliseconds, one must write12.003
, which the conversion treats as 12 + 0.003 = 12.003 seconds.Here is a more complex example:
to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')
is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds + 1230 microseconds = 2.021230 seconds. -
to_char(..., 'ID')’s day of the week numbering matches the `extract(isodow from ...)
function, but `to_char(..., 'D')’s does not match `extract(dow from ...)’s day numbering. -
to_char(interval)
formatsHH
andHH12
as shown on a 12-hour clock, for example zero hours and 36 hours both output as12
, whileHH24
outputs the full hour value, which can exceed 23 in aninterval
value.
Table 9.26 shows the template patterns available for formatting numeric values.
Table 9.26. Template Patterns for Numeric Formatting
Pattern | Description |
---|---|
|
digit position (can be dropped if insignificant) |
|
digit position (will not be dropped, even if insignificant) |
|
decimal point |
|
group (thousands) separator |
|
negative value in angle brackets |
|
sign anchored to number (uses locale) |
|
currency symbol (uses locale) |
|
decimal point (uses locale) |
|
group separator (uses locale) |
|
minus sign in specified position (if number < 0) |
|
plus sign in specified position (if number > 0) |
|
plus/minus sign in specified position |
|
Roman numeral (input between 1 and 3999) |
|
ordinal number suffix |
|
shift specified number of digits (see notes) |
|
exponent for scientific notation |
+
Usage notes for numeric formatting:
-
0
specifies a digit position that will always be printed, even if it contains a leading/trailing zero.9
also specifies a digit position, but if it is a leading zero then it will be replaced by a space, while if it is a trailing zero and fill mode is specified then it will be deleted. (Forto_number()
, these two pattern characters are equivalent.) -
The pattern characters
S
,L
,D
, andG
represent the sign, currency symbol, decimal point, and thousands separator characters defined by the current locale (see lc_monetary and lc_numeric). The pattern characters period and comma represent those exact characters, with the meanings of decimal point and thousands separator, regardless of locale. -
If no explicit provision is made for a sign in
to_char()’s pattern, one column will be reserved for the sign, and it will be anchored to (appear just left of) the number. If `S
appears just left of some `9’s, it will likewise be anchored to the number. -
A sign formatted using
SG
,PL
, orMI
is not anchored to the number; for example,to_char(-12, 'MI9999')
produces'- 12'
butto_char(-12, 'S9999')
produces' -12'
. (The Oracle implementation does not allow the use ofMI
before9
, but rather requires that9
precedeMI
.) -
TH
does not convert values less than zero and does not convert fractional numbers. -
PL
,SG
, andTH
are PostgreSQL extensions. -
V
withto_char
multiplies the input values by10^`
n, where
nis the number of digits following `V
.V
withto_number
divides in a similar manner.to_char
andto_number
do not support the use ofV
combined with a decimal point (e.g.,99.9V99
is not allowed). -
EEEE
(scientific notation) cannot be used in combination with any of the other formatting patterns or modifiers other than digit and decimal point patterns, and must be at the end of the format string (e.g.,9.99EEEE
is a valid pattern).
Certain modifiers can be applied to any template pattern to alter its behavior. For example, FM99.99
is the 99.99
pattern with the FM
modifier. Table 9.27 shows the modifier patterns for numeric formatting.
Table 9.27. Template Pattern Modifiers for Numeric Formatting
Modifier | Description | Example |
---|---|---|
|
fill mode (suppress trailing zeroes and padding blanks) |
|
|
upper case ordinal number suffix |
|
|
lower case ordinal number suffix |
|
+
Table 9.28 shows some examples of the use of the to_char
function.
Table 9.28. to_char
Examples
Expression | Result |
---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
+
Prev | Up | Next |
---|---|---|
9.7. Pattern Matching |
9.9. Date/Time Functions and Operators |
Copyright © 1996-2023 The PostgreSQL Global Development Group