Here are some quick and dirty examples for adding and subtracting days and months and finding the difference between dates in Oracle.

These examples select the result from the ‘dual’ table. Dual is a dummy table that exists in all Oracle databases. I am also using sysdate heavily. Sysdate simply returns the current date and time.

Adjusting Days, Weeks, Hours and Minutes

To add and subtract days from a date we simply use + or -. Here are some examples:

SQL> SELECT sysdate + 7 FROM dual;

SYSDATE+7
---------
06-DEC-05

SQL> SELECT sysdate - 30 FROM dual;

SYSDATE-3
---------
30-OCT-05

SQL> SELECT to_char(sysdate - 14, 'MM/DD/YYYY HH:MI AM') FROM dual;

TO_CHAR(SYSDATE-14,
-------------------
11/15/2005 09:41 AM

In the first example we see that the query returns 7 days from today. The second one shows 30 days before today. In the third query I have added the to_char function so we see hour and minute. This shows us that while the date has changed, the time has not.

The first and third examples above also show how adding days would be used to add weeks. If you wanted to simplify this you could add the logic into the query like this:

SQL> SELECT sysdate + (7 * 2) FROM dual;

SYSDATE+(
---------
13-DEC-05

Likewise to work with hours you would use fractional days. The simplest way to show this is by dividing the hours by 24 right in the query. The parentheses may not be necessary, but I feel they make the query a little clearer.

Here I show the current time, then the current time plus two hours:

SQL> SELECT to_char(sysdate, 'HH:MI AM') FROM dual;

TO_CHAR(
--------
09:48 AM

SQL> SELECT to_char(sysdate + (2/24), 'HH:MI AM') FROM dual;

TO_CHAR(
--------
11:48 AM

An alternative to this method is to use the numtodsinterval function. The example above can instead be written like this:

SQL> SELECT
to_char(sysdate + numtodsinterval(2, 'HOUR'), 'HH:MI AM')
FROM dual;

TO_CHAR(
--------
11:57 AM

Here the numtodsinterval function is doing the work of dividing 2/24 for hours. Valid options for the numtodsinterval are ‘DAY’, ‘HOUR’, ‘MINUTE’, or ‘SECOND’. Here is an example using ‘MINUTE’. When working with minutes the numtodsinterval function is much more readable.

SQL> SELECT
to_char(sysdate + numtodsinterval(45, 'MINUTE'), 'HH:MI AM')
FROM dual;

TO_CHAR(
--------
10:47 AM

Adjusting Months and Years

To work with months and years (either of which may have a varying number of days) Oracle has provided the function numtoyminterval. This works much like the numtodsinterval function mentioned above by taking a number and a string. Valid options for the string are ‘YEAR’ or ‘MONTH’.

SQL> SELECT
to_char(sysdate + numtoyminterval(5, 'MONTH'), 'MM/DD/YYYY')
FROM dual;

TO_CHAR(SY
----------
04/29/2006

SQL> SELECT
to_char(sysdate + numtoyminterval(2, 'YEAR'), 'MM/DD/YYYY')
FROM dual;

TO_CHAR(SY
----------
11/29/2007

Comparing dates

Let’s say we want to compare some dates and find out how many days or weeks between them. To simply see the result in days we can use the minus operator like this:

SQL> SELECT
TO_DATE('12/25/2005', 'MM/DD/YYYY') - sysdate
FROM dual;

TO_DATE('12/25/2005','MM/DD/YYYY')-SYSDATE
------------------------------------------
26.5124421

The result is expressed in days including fractional hours. Of course if we wanted weeks we could just divide by 7. Similarly if we’re looking for hours we could multiply by 24, but if we want months we need to use the months_between function.

SQL> SELECT
months_between(sysdate, to_date('01/01/2006', 'MM/DD/YYYY'))
FROM dual;

MONTHS_BETWEEN(SYSDATE,TO_DATE('01/01/2006','MM/DD/YYYY'))
----------------------------------------------------------
-1.0829409

Finding the Latest or Earliest Date in a Set

The Oracle functions greatest and least can be used on dates to return the latest or earliest date.

SQL> SELECT
greatest(sysdate, to_date('09/11/2005','MM/DD/YYYY'),
to_date('12/25/2005','MM/DD/YYYY'))
FROM dual;

GREATEST(
---------
25-DEC-05

SQL> SELECT
least(sysdate, to_date('09/11/2005','MM/DD/YYYY'),
to_date('12/25/2005','MM/DD/YYYY'))
FROM dual;

LEAST(SYS
---------
11-SEP-05

What’s the Last Day in a Given Month

The last_day function can be used to return the last day in a given month.

SQL> select last_day(sysdate) from dual;

LAST_DAY(
---------
30-NOV-05

Next Day of the Week After a Date

The next_day function gives the date of the next occurrence of a day of the week (‘Monday’, ‘Tuesday’, etc.) after a given date. Here we see the date of the next Sunday after today:

SQL> select next_day(sysdate,'Sunday') from dual;

NEXT_DAY(
---------
04-DEC-05

Still haven’t found what you’re looking for?

You may also want to look at these other articles:

Converting Time Zones in Oracle
Oracle, SQL, Dates and Timestamps
UNIX timestamp to Oracle Date Conversion

oracle, sql, dba, database administration, database development