Skip to main content

Date Format

The strftime and strptime functions can be used to convert between dates/timestamps and strings. This is often required when parsing CSV files, displaying output to the user or transferring information between programs. Because there are many possible date representations, these functions accept a format string that describes how the date or timestamp should be structured.

strftime examples

strftime(timestamp, format) converts timestamps or dates to strings according to the specified pattern.

SELECT strftime(DATE '1992-03-02', '%d/%m/%Y');
-- 02/03/1992
SELECT strftime(TIMESTAMP '1992-03-02 20:32:45', '%A, %-d %B %Y - %I:%M:%S %p');
-- Monday, 2 March 1992 - 08:32:45 PM
strptime examples

strptime(string, format) converts strings to timestamps according to the specified pattern.

SELECT strptime('02/03/1992', '%d/%m/%Y');
-- 1992-03-02 00:00:00
SELECT strptime('Monday, 2 March 1992 - 08:32:45 PM', '%A, %-d %B %Y - %I:%M:%S %p');
-- 1992-03-02 20:32:45
CSV Parsing

The date formats can also be specified during CSV parsing, either in the COPY statement or in the read_csv function. This can be done by either specifying a DATEFORMAT or a TIMESTAMPFORMAT (or both). DATEFORMAT will be used for converting dates, and TIMESTAMPFORMAT will be used for converting timestamps. Below are some examples for how to use this:

-- in COPY statement
COPY dates FROM 'test.csv' (DATEFORMAT '%d/%m/%Y', TIMESTAMPFORMAT '%A, %-d %B %Y - %I:%M:%S %p')

-- in read_csv function
SELECT * FROM read_csv('test.csv', dateformat='%m/%d/%Y');
Format Specifiers

Below is a full list of all available format specifiers.

SpecifierDescriptionExample
%aAbbreviated weekday name.Sun, Mon, ...
%AFull weekday name.Sunday, Monday, ...
%wWeekday as a decimal number.0, 1, ..., 6
%dDay of the month as a zero-padded decimal.01, 02, ..., 31
%-dDay of the month as a decimal number.1, 2, ..., 30
%bAbbreviated month name.Jan, Feb, ..., Dec
%BFull month name.January, February, ...
%mMonth as a zero-padded decimal number.01, 02, ..., 12
%-mMonth as a decimal number.1, 2, ..., 12
%yYear without century as a zero-padded decimal number.00, 01, ..., 99
%-yYear without century as a decimal number.0, 1, ..., 99
%YYear with century as a decimal number.2013, 2019 etc.
%HHour (24-hour clock) as a zero-padded decimal number.00, 01, ..., 23
%-HHour (24-hour clock) as a decimal number.0, 1, ..., 23
%IHour (12-hour clock) as a zero-padded decimal number.01, 02, ..., 12
%-IHour (12-hour clock) as a decimal number.1, 2, ... 12
%pLocale's AM or PM.AM, PM
%MMinute as a zero-padded decimal number.00, 01, ..., 59
%-MMinute as a decimal number.0, 1, ..., 59
%SSecond as a zero-padded decimal number.00, 01, ..., 59
%-SSecond as a decimal number.0, 1, ..., 59
%gMillisecond as a decimal number, zero-padded on the left.000 - 999
%fMicrosecond as a decimal number, zero-padded on the left.000000 - 999999
%zTime offset from UTC in the form ±HH:MM, ±HHMM, or ±HH.-0700
%ZTime zone name.Europe/Amsterdam
%jDay of the year as a zero-padded decimal number.001, 002, ..., 366
%-jDay of the year as a decimal number.1, 2, ..., 366
%UWeek number of the year (Sunday as the first day of the week).00, 01, ..., 53
%WWeek number of the year (Monday as the first day of the week).00, 01, ..., 53
%cISO date and time representation1992-03-02 10:30:20
%xISO date representation1992-03-02
%XISO time representation10:30:20
%%A literal '%' character.%