What is worst? To use DD-MON-RR or to use DD-MON-YY? When entering the birthday of my grandfather, I will write it as 31-JUL-1912, so both formats will be fine. If I enter it 31-JUL-12, both formats will be wrong. Ok, which date will I enter now and in the future? For short-time contracts I will enter dates like 01-AUG-08 or 31-DEC-11, both formats will be fine. For long time contracts like retirement saving plan I will enter 31-MAR-36, which is still fine, because I am old enough Juniors in my company will enter dates like 30-JUN-52, which will be fine with YY and wrong with RR or RRRR.
Ok, what is the recommended format then?
DD-MM-FXYYYY is probably fine. FX forces you to enter 4-digits years.
SQL> select
2 to_date('31-JUL-1912','DD-MON-YY') YY1912,
3 to_date('31-JUL-12','DD-MON-YY') YY12,
4 to_date('31-JUL-12','DD-MON-RR') RR12
5 from dual;
YY1912 YY12 RR12
---------- ---------- ----------
1912-07-31 2012-07-31 2012-07-31
SQL> select
2 to_date('31-MAR-2036','DD-MON-YY') YY2036,
3 to_date('31-MAR-36','DD-MON-YY') YY36,
4 to_date('31-MAR-36','DD-MON-RR') RR36
5 from dual;
YY2036 YY36 RR36
---------- ---------- ----------
2036-03-31 2036-03-31 2036-03-31
SQL> select
2 to_date('30-JUN-2052','DD-MON-YY') YY2052,
3 to_date('30-JUN-52','DD-MON-YY') YY52,
4 to_date('30-JUN-52','DD-MON-RR') RR52
5 from dual;
YY2052 YY52 RR52
---------- ---------- ----------
2052-06-30 2052-06-30 1952-06-30
SQL> select
2 to_date('8/4/2008','DD-MM-FXYYYY') FXYYYY2008
3 from dual;
FXYYYY2008
----------
2008-04-08
SQL> select
2 to_date('08-04-08','DD-MM-FXYYYY') FXYYYY08
3 from dual;
to_date('08-04-08','DD-MM-FXYYYY') FXYYYY08
*
ERROR at line 2:
ORA-01862: the numeric value does not match the length
of the format item
SQL>