Following the last post about time zones this post is about the display and default format of date and time values. What people usually do to get a consistent display of date and time values in Oracle is to set NLS_DATE_FORMAT:

SQL> show parameter nls_date_format;

NAME				     TYPE	 VALUE
------------------------------------ ----------- ------------------------------
nls_date_format 		     string	 YYYY-MON-DD HH24:MI:SS

SQL> alter session set nls_date_format='DD.MM.YYYY HH24:MI:SS';

Session altered.

SQL> select sysdate from dual;

SYSDATE
-------------------
29.03.2017 16:26:11

SQL> alter session set nls_date_format='YYYY-MON-DD HH24:MI:SS';

Session altered.

SQL> select sysdate from dual;

SYSDATE
--------------------
2017-MAR-29 16:31:01

Obviously PostgreSQL does not know anything about NLS_DATE_FORMAT, so what does it provide for doing the same?

First of all (and this is true for Oracle as well as for PostgreSQL) this is all about displaying date and time values and interpreting strings that shall be converted to date and time values. This has nothing to do with the internal storage.

What controls the display of date and time specific values in PostgreSQL is the parameter datestyle, the default is ISO:

postgres=# show datestyle;
 DateStyle 
-----------
 ISO, MDY
(1 row)

MDY here represents: MONTH-DAY-YEAR. If you want to change this on the session level you can:

postgres=# set datestyle='SQL, MDY';
SET
postgres=# select now();
              now               
--------------------------------
 03/29/2017 18:13:15.475693 GMT
(1 row)

You can do the same by setting the PGDATESTYLE environment variable before starting a new connection:

postgres@pgbox:/home/postgres/ [PG962] export PGDATESTYLE='SQL, MDY'
postgres@pgbox:/home/postgres/ [PG962] psql postgres
psql (9.6.2 dbi services build)
Type "help" for help.

postgres=# select now();
              now               
--------------------------------
 03/29/2017 18:15:29.765396 GMT
(1 row)

When you have a string and you want to insert that string into a column which is defined as date, how can you do this? PostgreSQL is very flexible here:

postgres=# create table t1 ( a date );
CREATE TABLE
postgres=# insert into t1 (a) values ('2017.01.01');
INSERT 0 1
postgres=# insert into t1 (a) values ('2017-01-01');
INSERT 0 1
postgres=# insert into t1 (a) values ('2017-JAN-01');
INSERT 0 1
postgres=# insert into t1 (a) values ('2017-JAN-01 11:11:11');
INSERT 0 1
postgres=# insert into t1 (a) values ('2017/01/01 11:11:11');
INSERT 0 1
postgres=# insert into t1 (a) values ('20170101 111111');
INSERT 0 1

All these work without specifying a format mask as you would need to do it in Oracle. The rules how a string is interpreted are documented here.

When you want to convert a string into a date or timestamp you can use one of the make_* functions:

postgres=# select make_date(2017,01,01);
 make_date  
------------
 2017-01-01
(1 row)
postgres=# select make_timestamp (2017,01,01,00,00,00);
   make_timestamp    
---------------------
 2017-01-01 00:00:00
(1 row)

… or use the data type formatting functions:

postgres=# select to_date('2017.01.01','YYYY.MM.DD');
  to_date   
------------
 2017-01-01
(1 row)

postgres=# select to_date('2017-JAN-01','YYYY.Mon.DD');
  to_date   
------------
 2017-01-01
(1 row)

Hope this helps …