2 9.8. Data Type Formatting Functions #
4 The PostgreSQL formatting functions provide a powerful set of tools for
5 converting various data types (date/time, integer, floating point,
6 numeric) to formatted strings and for converting from formatted strings
7 to specific data types. Table 9.26 lists them. These functions all
8 follow a common calling convention: the first argument is the value to
9 be formatted and the second argument is a template that defines the
10 output or input format.
12 Table 9.26. Formatting Functions
20 to_char ( timestamp, text ) → text
22 to_char ( timestamp with time zone, text ) → text
24 Converts time stamp to string according to the given format.
26 to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS') → 05:31:12
28 to_char ( interval, text ) → text
30 Converts interval to string according to the given format.
32 to_char(interval '15h 2m 12s', 'HH24:MI:SS') → 15:02:12
34 to_char ( numeric_type, text ) → text
36 Converts number to string according to the given format; available for
37 integer, bigint, numeric, real, double precision.
39 to_char(125, '999') → 125
41 to_char(125.8::real, '999D9') → 125.8
43 to_char(-125.8, '999D99S') → 125.80-
45 to_date ( text, text ) → date
47 Converts string to date according to the given format.
49 to_date('05 Dec 2000', 'DD Mon YYYY') → 2000-12-05
51 to_number ( text, text ) → numeric
53 Converts string to numeric according to the given format.
55 to_number('12,454.8-', '99G999D9S') → -12454.8
57 to_timestamp ( text, text ) → timestamp with time zone
59 Converts string to time stamp according to the given format. (See also
60 to_timestamp(double precision) in Table 9.33.)
62 to_timestamp('05 Dec 2000', 'DD Mon YYYY') → 2000-12-05 00:00:00-05
66 to_timestamp and to_date exist to handle input formats that cannot be
67 converted by simple casting. For most standard date/time formats,
68 simply casting the source string to the required data type works, and
69 is much easier. Similarly, to_number is unnecessary for standard
70 numeric representations.
72 In a to_char output template string, there are certain patterns that
73 are recognized and replaced with appropriately-formatted data based on
74 the given value. Any text that is not a template pattern is simply
75 copied verbatim. Similarly, in an input template string (for the other
76 functions), template patterns identify the values to be supplied by the
77 input data string. If there are characters in the template string that
78 are not template patterns, the corresponding characters in the input
79 data string are simply skipped over (whether or not they are equal to
80 the template string characters).
82 Table 9.27 shows the template patterns available for formatting date
85 Table 9.27. Template Patterns for Date/Time Formatting
87 HH hour of day (01–12)
88 HH12 hour of day (01–12)
89 HH24 hour of day (00–23)
92 MS millisecond (000–999)
93 US microsecond (000000–999999)
94 FF1 tenth of second (0–9)
95 FF2 hundredth of second (00–99)
96 FF3 millisecond (000–999)
97 FF4 tenth of a millisecond (0000–9999)
98 FF5 hundredth of a millisecond (00000–99999)
99 FF6 microsecond (000000–999999)
100 SSSS, SSSSS seconds past midnight (0–86399)
101 AM, am, PM or pm meridiem indicator (without periods)
102 A.M., a.m., P.M. or p.m. meridiem indicator (with periods)
103 Y,YYY year (4 or more digits) with comma
104 YYYY year (4 or more digits)
105 YYY last 3 digits of year
106 YY last 2 digits of year
108 IYYY ISO 8601 week-numbering year (4 or more digits)
109 IYY last 3 digits of ISO 8601 week-numbering year
110 IY last 2 digits of ISO 8601 week-numbering year
111 I last digit of ISO 8601 week-numbering year
112 BC, bc, AD or ad era indicator (without periods)
113 B.C., b.c., A.D. or a.d. era indicator (with periods)
114 MONTH full upper case month name (blank-padded to 9 chars)
115 Month full capitalized month name (blank-padded to 9 chars)
116 month full lower case month name (blank-padded to 9 chars)
117 MON abbreviated upper case month name (3 chars in English, localized
119 Mon abbreviated capitalized month name (3 chars in English, localized
121 mon abbreviated lower case month name (3 chars in English, localized
123 MM month number (01–12)
124 DAY full upper case day name (blank-padded to 9 chars)
125 Day full capitalized day name (blank-padded to 9 chars)
126 day full lower case day name (blank-padded to 9 chars)
127 DY abbreviated upper case day name (3 chars in English, localized
129 Dy abbreviated capitalized day name (3 chars in English, localized
131 dy abbreviated lower case day name (3 chars in English, localized
133 DDD day of year (001–366)
134 IDDD day of ISO 8601 week-numbering year (001–371; day 1 of the year is
135 Monday of the first ISO week)
136 DD day of month (01–31)
137 D day of the week, Sunday (1) to Saturday (7)
138 ID ISO 8601 day of the week, Monday (1) to Sunday (7)
139 W week of month (1–5) (the first week starts on the first day of the
141 WW week number of year (1–53) (the first week starts on the first day
143 IW week number of ISO 8601 week-numbering year (01–53; the first
144 Thursday of the year is in week 1)
145 CC century (2 digits) (the twenty-first century starts on 2001-01-01)
146 J Julian Date (integer days since November 24, 4714 BC at local
147 midnight; see Section B.7)
149 RM month in upper case Roman numerals (I–XII; I=January)
150 rm month in lower case Roman numerals (i–xii; i=January)
151 TZ upper case time-zone abbreviation
152 tz lower case time-zone abbreviation
154 TZM time-zone minutes
155 OF time-zone offset from UTC (HH or HH:MM)
157 Modifiers can be applied to any template pattern to alter its behavior.
158 For example, FMMonth is the Month pattern with the FM modifier.
159 Table 9.28 shows the modifier patterns for date/time formatting.
161 Table 9.28. Template Pattern Modifiers for Date/Time Formatting
162 Modifier Description Example
163 FM prefix fill mode (suppress leading zeroes and padding blanks)
165 TH suffix upper case ordinal number suffix DDTH, e.g., 12TH
166 th suffix lower case ordinal number suffix DDth, e.g., 12th
167 FX prefix fixed format global option (see usage notes) FX Month DD Day
168 TM prefix translation mode (use localized day and month names based on
170 SP suffix spell mode (not implemented) DDSP
172 Usage notes for date/time formatting:
173 * FM suppresses leading zeroes and trailing blanks that would
174 otherwise be added to make the output of a pattern be fixed-width.
175 In PostgreSQL, FM modifies only the next specification, while in
176 Oracle FM affects all subsequent specifications, and repeated FM
177 modifiers toggle fill mode on and off.
178 * TM suppresses trailing blanks whether or not FM is specified.
179 * to_timestamp and to_date ignore letter case in the input; so for
180 example MON, Mon, and mon all accept the same strings. When using
181 the TM modifier, case-folding is done according to the rules of the
182 function's input collation (see Section 23.2).
183 * to_timestamp and to_date skip multiple blank spaces at the
184 beginning of the input string and around date and time values
185 unless the FX option is used. For example,
186 to_timestamp(' 2000 JUN', 'YYYY MON') and to_timestamp('2000 -
187 JUN', 'YYYY-MON') work, but to_timestamp('2000 JUN', 'FXYYYY
188 MON') returns an error because to_timestamp expects only a single
189 space. FX must be specified as the first item in the template.
190 * A separator (a space or non-letter/non-digit character) in the
191 template string of to_timestamp and to_date matches any single
192 separator in the input string or is skipped, unless the FX option
193 is used. For example, to_timestamp('2000JUN', 'YYYY///MON') and
194 to_timestamp('2000/JUN', 'YYYY MON') work, but
195 to_timestamp('2000//JUN', 'YYYY/MON') returns an error because the
196 number of separators in the input string exceeds the number of
197 separators in the template.
198 If FX is specified, a separator in the template string matches
199 exactly one character in the input string. But note that the input
200 string character is not required to be the same as the separator
201 from the template string. For example, to_timestamp('2000/JUN',
202 'FXYYYY MON') works, but to_timestamp('2000/JUN', 'FXYYYY MON')
203 returns an error because the second space in the template string
204 consumes the letter J from the input string.
205 * A TZH template pattern can match a signed number. Without the FX
206 option, minus signs may be ambiguous, and could be interpreted as a
207 separator. This ambiguity is resolved as follows: If the number of
208 separators before TZH in the template string is less than the
209 number of separators before the minus sign in the input string, the
210 minus sign is interpreted as part of TZH. Otherwise, the minus sign
211 is considered to be a separator between values. For example,
212 to_timestamp('2000 -10', 'YYYY TZH') matches -10 to TZH, but
213 to_timestamp('2000 -10', 'YYYY TZH') matches 10 to TZH.
214 * Ordinary text is allowed in to_char templates and will be output
215 literally. You can put a substring in double quotes to force it to
216 be interpreted as literal text even if it contains template
217 patterns. For example, in '"Hello Year "YYYY', the YYYY will be
218 replaced by the year data, but the single Y in Year will not be. In
219 to_date, to_number, and to_timestamp, literal text and
220 double-quoted strings result in skipping the number of characters
221 contained in the string; for example "XX" skips two input
222 characters (whether or not they are XX).
225 Prior to PostgreSQL 12, it was possible to skip arbitrary text in
226 the input string using non-letter or non-digit characters. For
227 example, to_timestamp('2000y6m1d', 'yyyy-MM-DD') used to work. Now
228 you can only use letter characters for this purpose. For example,
229 to_timestamp('2000y6m1d', 'yyyytMMtDDt') and
230 to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"') skip y, m, and d.
231 * If you want to have a double quote in the output you must precede
232 it with a backslash, for example '\"YYYY Month\"'. Backslashes are
233 not otherwise special outside of double-quoted strings. Within a
234 double-quoted string, a backslash causes the next character to be
235 taken literally, whatever it is (but this has no special effect
236 unless the next character is a double quote or another backslash).
237 * In to_timestamp and to_date, if the year format specification is
238 less than four digits, e.g., YYY, and the supplied year is less
239 than four digits, the year will be adjusted to be nearest to the
240 year 2020, e.g., 95 becomes 1995.
241 * In to_timestamp and to_date, negative years are treated as
242 signifying BC. If you write both a negative year and an explicit BC
243 field, you get AD again. An input of year zero is treated as 1 BC.
244 * In to_timestamp and to_date, the YYYY conversion has a restriction
245 when processing years with more than 4 digits. You must use some
246 non-digit character or template after YYYY, otherwise the year is
247 always interpreted as 4 digits. For example (with the year 20000):
248 to_date('200001130', 'YYYYMMDD') will be interpreted as a 4-digit
249 year; instead use a non-digit separator after the year, like
250 to_date('20000-1130', 'YYYY-MMDD') or to_date('20000Nov30',
252 * In to_timestamp and to_date, the CC (century) field is accepted but
253 ignored if there is a YYY, YYYY or Y,YYY field. If CC is used with
254 YY or Y then the result is computed as that year in the specified
255 century. If the century is specified but the year is not, the first
256 year of the century is assumed.
257 * In to_timestamp and to_date, weekday names or numbers (DAY, D, and
258 related field types) are accepted but are ignored for purposes of
259 computing the result. The same is true for quarter (Q) fields.
260 * In to_timestamp and to_date, an ISO 8601 week-numbering date (as
261 distinct from a Gregorian date) can be specified in one of two
263 + Year, week number, and weekday: for example
264 to_date('2006-42-4', 'IYYY-IW-ID') returns the date
265 2006-10-19. If you omit the weekday it is assumed to be 1
267 + Year and day of year: for example to_date('2006-291',
268 'IYYY-IDDD') also returns 2006-10-19.
269 Attempting to enter a date using a mixture of ISO 8601
270 week-numbering fields and Gregorian date fields is nonsensical, and
271 will cause an error. In the context of an ISO 8601 week-numbering
272 year, the concept of a “month” or “day of month” has no meaning. In
273 the context of a Gregorian year, the ISO week has no meaning.
276 While to_date will reject a mixture of Gregorian and ISO
277 week-numbering date fields, to_char will not, since output format
278 specifications like YYYY-MM-DD (IYYY-IDDD) can be useful. But avoid
279 writing something like IYYY-MM-DD; that would yield surprising
280 results near the start of the year. (See Section 9.9.1 for more
282 * In to_timestamp, millisecond (MS) or microsecond (US) fields are
283 used as the seconds digits after the decimal point. For example
284 to_timestamp('12.3', 'SS.MS') is not 3 milliseconds, but 300,
285 because the conversion treats it as 12 + 0.3 seconds. So, for the
286 format SS.MS, the input values 12.3, 12.30, and 12.300 specify the
287 same number of milliseconds. To get three milliseconds, one must
288 write 12.003, which the conversion treats as 12 + 0.003 = 12.003
290 Here is a more complex example: to_timestamp('15:12:02.020.001230',
291 'HH24:MI:SS.MS.US') is 15 hours, 12 minutes, and 2 seconds + 20
292 milliseconds + 1230 microseconds = 2.021230 seconds.
293 * to_char(..., 'ID')'s day of the week numbering matches the
294 extract(isodow from ...) function, but to_char(..., 'D')'s does not
295 match extract(dow from ...)'s day numbering.
296 * to_char(interval) formats HH and HH12 as shown on a 12-hour clock,
297 for example zero hours and 36 hours both output as 12, while HH24
298 outputs the full hour value, which can exceed 23 in an interval
301 Table 9.29 shows the template patterns available for formatting numeric
304 Table 9.29. Template Patterns for Numeric Formatting
306 9 digit position (can be dropped if insignificant)
307 0 digit position (will not be dropped, even if insignificant)
308 . (period) decimal point
309 , (comma) group (thousands) separator
310 PR negative value in angle brackets
311 S sign anchored to number (uses locale)
312 L currency symbol (uses locale)
313 D decimal point (uses locale)
314 G group separator (uses locale)
315 MI minus sign in specified position (if number < 0)
316 PL plus sign in specified position (if number > 0)
317 SG plus/minus sign in specified position
318 RN or rn Roman numeral (values between 1 and 3999)
319 TH or th ordinal number suffix
320 V shift specified number of digits (see notes)
321 EEEE exponent for scientific notation
323 Usage notes for numeric formatting:
324 * 0 specifies a digit position that will always be printed, even if
325 it contains a leading/trailing zero. 9 also specifies a digit
326 position, but if it is a leading zero then it will be replaced by a
327 space, while if it is a trailing zero and fill mode is specified
328 then it will be deleted. (For to_number(), these two pattern
329 characters are equivalent.)
330 * If the format provides fewer fractional digits than the number
331 being formatted, to_char() will round the number to the specified
332 number of fractional digits.
333 * The pattern characters S, L, D, and G represent the sign, currency
334 symbol, decimal point, and thousands separator characters defined
335 by the current locale (see lc_monetary and lc_numeric). The pattern
336 characters period and comma represent those exact characters, with
337 the meanings of decimal point and thousands separator, regardless
339 * If no explicit provision is made for a sign in to_char()'s pattern,
340 one column will be reserved for the sign, and it will be anchored
341 to (appear just left of) the number. If S appears just left of some
342 9's, it will likewise be anchored to the number.
343 * A sign formatted using SG, PL, or MI is not anchored to the number;
344 for example, to_char(-12, 'MI9999') produces '- 12' but
345 to_char(-12, 'S9999') produces ' -12'. (The Oracle implementation
346 does not allow the use of MI before 9, but rather requires that 9
348 * TH does not convert values less than zero and does not convert
350 * PL, SG, and TH are PostgreSQL extensions.
351 * In to_number, if non-data template patterns such as L or TH are
352 used, the corresponding number of input characters are skipped,
353 whether or not they match the template pattern, unless they are
354 data characters (that is, digits, sign, decimal point, or comma).
355 For example, TH would skip two non-data characters.
356 * V with to_char multiplies the input values by 10^n, where n is the
357 number of digits following V. V with to_number divides in a similar
358 manner. The V can be thought of as marking the position of an
359 implicit decimal point in the input or output string. to_char and
360 to_number do not support the use of V combined with a decimal point
361 (e.g., 99.9V99 is not allowed).
362 * EEEE (scientific notation) cannot be used in combination with any
363 of the other formatting patterns or modifiers other than digit and
364 decimal point patterns, and must be at the end of the format string
365 (e.g., 9.99EEEE is a valid pattern).
366 * In to_number(), the RN pattern converts Roman numerals (in standard
367 form) to numbers. Input is case-insensitive, so RN and rn are
368 equivalent. RN cannot be used in combination with any other
369 formatting patterns or modifiers except FM, which is applicable
370 only in to_char() and is ignored in to_number().
372 Certain modifiers can be applied to any template pattern to alter its
373 behavior. For example, FM99.99 is the 99.99 pattern with the FM
374 modifier. Table 9.30 shows the modifier patterns for numeric
377 Table 9.30. Template Pattern Modifiers for Numeric Formatting
378 Modifier Description Example
379 FM prefix fill mode (suppress trailing zeroes and padding blanks)
381 TH suffix upper case ordinal number suffix 999TH
382 th suffix lower case ordinal number suffix 999th
384 Table 9.31 shows some examples of the use of the to_char function.
386 Table 9.31. to_char Examples
388 to_char(current_timestamp, 'Day, DD HH12:MI:SS')
389 'Tuesday , 06 05:39:18'
390 to_char(current_timestamp, 'FMDay, FMDD HH12:MI:SS')
391 'Tuesday, 6 05:39:18'
392 to_char(current_timestamp AT TIME ZONE 'UTC',
393 'YYYY-MM-DD"T"HH24:MI:SS"Z"') '2022-12-06T05:39:18Z', ISO 8601 extended
395 to_char(-0.1, '99.99') ' -.10'
396 to_char(-0.1, 'FM9.99') '-.1'
397 to_char(-0.1, 'FM90.99') '-0.1'
398 to_char(0.1, '0.9') ' 0.1'
399 to_char(12, '9990999.9') ' 0012.0'
400 to_char(12, 'FM9990999.9') '0012.'
401 to_char(485, '999') ' 485'
402 to_char(-485, '999') '-485'
403 to_char(485, '9 9 9') ' 4 8 5'
404 to_char(1485, '9,999') ' 1,485'
405 to_char(1485, '9G999') ' 1 485'
406 to_char(148.5, '999.999') ' 148.500'
407 to_char(148.5, 'FM999.999') '148.5'
408 to_char(148.5, 'FM999.990') '148.500'
409 to_char(148.5, '999D999') ' 148,500'
410 to_char(3148.5, '9G999D999') ' 3 148,500'
411 to_char(-485, '999S') '485-'
412 to_char(-485, '999MI') '485-'
413 to_char(485, '999MI') '485 '
414 to_char(485, 'FM999MI') '485'
415 to_char(485, 'PL999') '+485'
416 to_char(485, 'SG999') '+485'
417 to_char(-485, 'SG999') '-485'
418 to_char(-485, '9SG99') '4-85'
419 to_char(-485, '999PR') '<485>'
420 to_char(485, 'L999') 'DM 485'
421 to_char(485, 'RN') ' CDLXXXV'
422 to_char(485, 'FMRN') 'CDLXXXV'
423 to_char(5.2, 'FMRN') 'V'
424 to_char(482, '999th') ' 482nd'
425 to_char(485, '"Good number:"999') 'Good number: 485'
426 to_char(485.8, '"Pre:"999" Post:" .999') 'Pre: 485 Post: .800'
427 to_char(12, '99V999') ' 12000'
428 to_char(12.4, '99V999') ' 12400'
429 to_char(12.45, '99V9') ' 125'
430 to_char(0.0004859, '9.99EEEE') ' 4.86e-04'