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.26 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.26. Formatting Functions

Function

Description

Example(s)

to_char ( timestamp, text ) → text

to_char ( timestamp with time zone, text ) → text

Converts time stamp to string according to the given format.

to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')05:31:12

to_char ( interval, text ) → text

Converts interval to string according to the given format.

to_char(interval '15h 2m 12s', 'HH24:MI:SS')15:02:12

to_char ( numeric_type, text ) → text

Converts number to string according to the given format; available for integer, bigint, numeric, real, double precision.

to_char(125, '999')125

to_char(125.8::real, '999D9')125.8

to_char(-125.8, '999D99S')125.80-

to_date ( text, text ) → date

Converts string to date according to the given format.

to_date('05 Dec 2000', 'DD Mon YYYY')2000-12-05

to_number ( text, text ) → numeric

Converts string to numeric according to the given format.

to_number('12,454.8-', '99G999D9S')-12454.8

to_timestamp ( text, text ) → timestamp with time zone

Converts string to time stamp according to the given format. (See also to_timestamp(double precision) in Table 9.33.)

to_timestamp('05 Dec 2000', 'DD Mon YYYY')2000-12-05 00:00:00-05


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. If there are characters in the template string that are not template patterns, the corresponding characters in the input data string are simply skipped over (whether or not they are equal to the template string characters).

Table 9.27 shows the template patterns available for formatting date and time values.

Table 9.27. Template Patterns for Date/Time Formatting

PatternDescription
HHhour of day (01–12)
HH12hour of day (01–12)
HH24hour of day (00–23)
MIminute (00–59)
SSsecond (00–59)
MSmillisecond (000–999)
USmicrosecond (000000–999999)
FF1tenth of second (0–9)
FF2hundredth of second (00–99)
FF3millisecond (000–999)
FF4tenth of a millisecond (0000–9999)
FF5hundredth of a millisecond (00000–99999)
FF6microsecond (000000–999999)
SSSS, SSSSSseconds past midnight (0–86399)
AM, am, PM or pmmeridiem indicator (without periods)
A.M., a.m., P.M. or p.m.meridiem indicator (with periods)
Y,YYYyear (4 or more digits) with comma
YYYYyear (4 or more digits)
YYYlast 3 digits of year
YYlast 2 digits of year
Ylast digit of year
IYYYISO 8601 week-numbering year (4 or more digits)
IYYlast 3 digits of ISO 8601 week-numbering year
IYlast 2 digits of ISO 8601 week-numbering year
Ilast digit of ISO 8601 week-numbering year
BC, bc, AD or adera indicator (without periods)
B.C., b.c., A.D. or a.d.era indicator (with periods)
MONTHfull upper case month name (blank-padded to 9 chars)
Monthfull capitalized month name (blank-padded to 9 chars)
monthfull lower case month name (blank-padded to 9 chars)
MONabbreviated upper case month name (3 chars in English, localized lengths vary)
Monabbreviated capitalized month name (3 chars in English, localized lengths vary)
monabbreviated lower case month name (3 chars in English, localized lengths vary)
MMmonth number (01–12)
DAYfull upper case day name (blank-padded to 9 chars)
Dayfull capitalized day name (blank-padded to 9 chars)
dayfull lower case day name (blank-padded to 9 chars)
DYabbreviated upper case day name (3 chars in English, localized lengths vary)
Dyabbreviated capitalized day name (3 chars in English, localized lengths vary)
dyabbreviated lower case day name (3 chars in English, localized lengths vary)
DDDday of year (001–366)
IDDDday of ISO 8601 week-numbering year (001–371; day 1 of the year is Monday of the first ISO week)
DDday of month (01–31)
Dday of the week, Sunday (1) to Saturday (7)
IDISO 8601 day of the week, Monday (1) to Sunday (7)
Wweek of month (1–5) (the first week starts on the first day of the month)
WWweek number of year (1–53) (the first week starts on the first day of the year)
IWweek number of ISO 8601 week-numbering year (01–53; the first Thursday of the year is in week 1)
CCcentury (2 digits) (the twenty-first century starts on 2001-01-01)
JJulian Date (integer days since November 24, 4714 BC at local midnight; see Section B.7)
Qquarter
RMmonth in upper case Roman numerals (I–XII; I=January)
rmmonth in lower case Roman numerals (i–xii; i=January)
TZupper case time-zone abbreviation (only supported in to_char)
tzlower case time-zone abbreviation (only supported in to_char)
TZHtime-zone hours
TZMtime-zone minutes
OFtime-zone offset from UTC (only supported in to_char)

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.28 shows the modifier patterns for date/time formatting.

Table 9.28. Template Pattern Modifiers for Date/Time Formatting

ModifierDescriptionExample
FM prefixfill mode (suppress leading zeroes and padding blanks)FMMonth
TH suffixupper case ordinal number suffixDDTH, e.g., 12TH
th suffixlower case ordinal number suffixDDth, e.g., 12th
FX prefixfixed format global option (see usage notes)FX Month DD Day
TM prefixtranslation mode (use localized day and month names based on lc_time)TMMonth
SP suffixspell mode (not implemented)DDSP

Usage notes for date/time formatting:

Table 9.29 shows the template patterns available for formatting numeric values.

Table 9.29. Template Patterns for Numeric Formatting

PatternDescription
9digit position (can be dropped if insignificant)
0digit position (will not be dropped, even if insignificant)
. (period)decimal point
, (comma)group (thousands) separator
PRnegative value in angle brackets
Ssign anchored to number (uses locale)
Lcurrency symbol (uses locale)
Ddecimal point (uses locale)
Ggroup separator (uses locale)
MIminus sign in specified position (if number < 0)
PLplus sign in specified position (if number > 0)
SGplus/minus sign in specified position
RNRoman numeral (input between 1 and 3999)
TH or thordinal number suffix
Vshift specified number of digits (see notes)
EEEEexponent for scientific notation

Usage notes for numeric formatting:

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.30 shows the modifier patterns for numeric formatting.

Table 9.30. Template Pattern Modifiers for Numeric Formatting

ModifierDescriptionExample
FM prefixfill mode (suppress trailing zeroes and padding blanks)FM99.99
TH suffixupper case ordinal number suffix999TH
th suffixlower case ordinal number suffix999th

Table 9.31 shows some examples of the use of the to_char function.

Table 9.31. to_char Examples

ExpressionResult
to_char(current_timestamp, 'Day, DD  HH12:MI:SS')'Tuesday  , 06  05:39:18'
to_char(current_timestamp, 'FMDay, FMDD  HH12:MI:SS')'Tuesday, 6  05:39:18'
to_char(-0.1, '99.99')'  -.10'
to_char(-0.1, 'FM9.99')'-.1'
to_char(-0.1, 'FM90.99')'-0.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(485, '9 9 9')' 4 8 5'
to_char(1485, '9,999')' 1,485'
to_char(1485, '9G999')' 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(148.5, '999D999')' 148,500'
to_char(3148.5, '9G999D999')' 3 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, 'PL999')'+485'
to_char(485, 'SG999')'+485'
to_char(-485, 'SG999')'-485'
to_char(-485, '9SG99')'4-85'
to_char(-485, '999PR')'<485>'
to_char(485, 'L999')'DM 485'
to_char(485, 'RN')'        CDLXXXV'
to_char(485, 'FMRN')'CDLXXXV'
to_char(5.2, 'FMRN')'V'
to_char(482, '999th')' 482nd'
to_char(485, '"Good number:"999')'Good number: 485'
to_char(485.8, '"Pre:"999" Post:" .999')'Pre: 485 Post: .800'
to_char(12, '99V999')' 12000'
to_char(12.4, '99V999')' 12400'
to_char(12.45, '99V9')' 125'
to_char(0.0004859, '9.99EEEE')' 4.86e-04'