Working with dates and time stamps in PL/SQL

October 2, 2020 | 11 minute read
Steven Feuerstein
Developer Advocate for PL/SQL
Text Size 100%:

Part 5 in a series of articles on understanding and using PL/SQL for accessing Oracle Database

PL/SQL is one of the core technologies at Oracle and is essential to leveraging the full potential of Oracle Database. PL/SQL combines the relational data access capabilities of the Structured Query Language with a flexible embedded procedural language, and it executes complex queries and programmatic logic run inside the database engine itself. This enhances the agility, efficiency, and performance of database-driven applications.

Steven Feuerstein, one of the industry’s best-respected and most prolific experts in PL/SQL, wrote a 12-part tutorial series on the language. Those articles, first published in 2011, have been among the most popular ever published on the Oracle website and continue to find new readers and enthusiasts in the database community. Beginning with the first installment, the entire series is being updated and republished; please enjoy!

The previous articles in this introductory PL/SQL series focused on strings and numbers in PL/SQL-based applications, but it is a very rare business application that does not also rely on dates and often on times. You need to keep track of when events happened, when people were born, when a transaction occurred, and much more.

As a result, you will quite often need to

  • Declare variables and constants for dates
  • Use built-in functions to display and modify date values
  • Perform computations on dates

A date is a considerably more complex data type than a string or a number. It has multiple parts (year, month, day, hour, minute, second), and there are many rules about what constitutes a valid date. This article gives you all the information you need to begin working with dates in your PL/SQL programs.

Unlike strings and numbers, dates are quite complicated: Not only are they highly formatted data but there are also many rules for determining valid values and valid calculations, such as leap days and leap years, daylight saving time changes, national and company holidays, and counting the days in date ranges.

Fortunately, Oracle Database and PL/SQL provide a set of true date and time data types that store both date and time information in a standard internal format, and they also have an extensive set of built-in functions for manipulating the date and time.

There are three data types you can use to work with dates and times:

  • DATE—This data type stores a date and a time, resolved to the second. It does not include the time zone. DATE is the oldest and most commonly used data type for working with dates in Oracle applications.
  • TIMESTAMP—Time stamps are similar to dates but with these two key distinctions: (1) You can store and manipulate times resolved to the nearest billionth of a second (nine decimal places of precision), and (2) you can associate a time zone with a time stamp, and Oracle Database will take that time zone into account when manipulating the time stamp.
  • INTERVAL—Whereas DATE and TIMESTAMP record a specific point in time, INTERVAL records and computes a time duration. You can specify an interval in terms of years and months, or days and seconds.

Listing 1 includes example variables whose declaration is based on these data types.

Code listing 1: Declaring DATE, TIMESTAMP, and INTERVAL variables

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
DECLARE
   l_today_date        DATE := SYSDATE;
   l_today_timestamp   TIMESTAMP := SYSTIMESTAMP;
   l_today_timetzone   TIMESTAMP WITH TIME ZONE := SYSTIMESTAMP;
   l_interval1         INTERVAL YEAR (4) TO MONTH := '2011-11';
   l_interval2         INTERVAL DAY (2) TO SECOND := '15 00:30:44';
BEGIN
   null;
END;

Working with intervals and time stamps with time zones can be very complicated; relatively few developers will need these more advanced features. This article focuses on the core DATE and TIMESTAMP types, along with the most commonly used built-in functions.

Choosing a data type. With such an abundance of riches, how do you decide which of these date and time data types to use? Here are some guidelines:

  • Use one of the TIMESTAMP types if you need to track time down to a fraction of a second.
  • You can, in general, use TIMESTAMP in place of DATE. A time stamp does not contain subsecond precision and takes only 7 bytes of storage, just as a DATE data type does. When your time stamp does contain subsecond data, it takes up 11 bytes of storage.
  • Use TIMESTAMP WITH TIME ZONE if you need to keep track of the session time zone in which the data was entered.
  • Use TIMESTAMP WITH LOCAL TIME ZONE if you want the database to automatically convert a time between the database and session time zones.
  • Use DATE when it’s necessary to maintain compatibility with an existing application written before any of the TIMESTAMP data types were introduced.
  • Use data types in your PL/SQL code that correspond to, or are at least compatible with, the underlying database tables. Think twice, for example, before reading a TIMESTAMP value from a table into a DATE variable, because you might lose information (in this case, the fractional seconds and perhaps the time zone).

Getting the current date and time. PL/SQL developers often need to retrieve and work with the current date and time. Many developers use the SYSDATE function, but that’s not your only choice. Oracle Database offers several functions to provide variations of this information, as shown in Table 1.

Function Time zone Data type returned
CURRENT_DATE Session DATE
CURRENT_TIMESTAMP Session TIMESTAMP WITH TIME ZONE
LOCALTIMESTAMP Session TIMESTAMP
SYSDATE Database server DATE
SYSTIMESTAMP Database server TIMESTAMP WITH TIME ZONE

Table 1: SYSDATE and other options for working with the current date and time

Listing 2 displays the values returned by calls to SYSDATE and SYSTIMESTAMP.

Code listing 2: Calls to SYSDATE and SYSTIMESTAMP and the returned values

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
BEGIN
  DBMS_OUTPUT.put_line (SYSDATE);
  DBMS_OUTPUT.put_line (SYSTIMESTAMP);
  DBMS_OUTPUT.put_line (SYSDATE - SYSTIMESTAMP);
END;
/

Here is the output:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
07-AUG-11
07-AUG-11 08.46.16.379000000 AM -05:00
-000000000 00:00:00.379000000

Because I have passed dates and time stamps to DBMS_OUTPUT.PUT_LINE, Oracle Database implicitly converts them to strings, using the default format masks for the database or the session (as specified by the National Language Settings NLS_DATE_FORMAT parameter). A default installation of Oracle Database sets the default DATE format to DD-MON-YYYY. The default TIMESTAMP format includes both the date offset and the time zone offset.

Note that it is possible to perform date arithmetic: I subtract the value returned by SYSTIMESTAMP from the value returned by SYSDATE. The result is an interval that is very close (but not quite equal) to zero.

Converting dates to strings and strings to dates. As with TO_CHAR for numbers, you use another version of the TO_CHAR function to convert a date or a time stamp to a string. And again, as with numbers, Oracle Database offers a large set of format elements to help you tweak that string to appear exactly as you need it. Here are some examples:

  • Use TO_CHAR without a format mask. If you do not include a format mask, the string returned by TO_CHAR will be the same as that returned when Oracle Database performs an implicit conversion:
    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
       DBMS_OUTPUT.put_line (
         TO_CHAR (SYSDATE));
       DBMS_OUTPUT.put_line (
         TO_CHAR (SYSTIMESTAMP));
    END;
    / 
    07-AUG-11
    07-AUG-11 08.55.00.470000000 AM -05:00
  • Use TO_CHAR to display the full names of both the day and the month in the date:
    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
       DBMS_OUTPUT.put_line (
    TO_CHAR (SYSDATE, 
    'Day, DDth Month YYYY'));
    END;
    /
    Sunday   , 07TH August    2011

    Note: The language used to display these names is determined by the NLS_DATE_LANGUAGE setting, which can also be specified as the third argument in the call to TO_CHAR, as in

    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
      DBMS_OUTPUT.put_line (
        TO_CHAR (SYSDATE, 
    'Day, DDth Month YYYY', 
    'NLS_DATE_LANGUAGE=Spanish'));
    END;
    /
    Domingo  , 07TH Agosto     2011
  • Use TO_CHAR to display the full names of both the day and the month in the date—but without all those extra spaces in the date-as-string. Oracle Database, by default, pads the string with spaces to match the maximum length of the day or the month. In most situations, you don’t want to include that extra text, and Oracle Database offers a format element modifier, FM, to control blank and zero padding. In the following block, I prefix the format mask with FM and remove the 0 (before 7) and extra spaces after August:
    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
      DBMS_OUTPUT.put_line (
         TO_CHAR (SYSDATE, 
    'FMDay, DDth Month YYYY'));
    END;
    /
    Sunday, 7TH August 2011

You can also use the format mask to extract a portion of the date information, as shown in the following examples:

  • What quarter is it?
    TO_CHAR (SYSDATE, 'Q')
  • What is the day of the year (1-366) for today’s date?
    TO_CHAR (SYSDATE, 'DDD')
  • What are the date and time of a DATE variable? (This is a very common requirement, because the default format mask for a date does not include the time component, which means that asking DBMS_OUTPUT.PUT_LINE to display a date leaves out the time.)
    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
      DBMS_OUTPUT.put_line (
        TO_CHAR (SYSDATE, 
    'YYYY-MM-DD HH24:MI:SS'));
    END;
    /

You can also use EXTRACT to extract and return the value of a specified element of a date, for example:

  • What year is it?
    EXTRACT (YEAR FROM SYSDATE)
  • What is the day for today’s date?
    EXTRACT (DAY FROM SYSDATE)

To convert a string to a date, use the TO_DATE or the TO_TIMESTAMP built-in function. Provide the string and Oracle Database returns a date or a time stamp, using the default format mask for the session:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
DECLARE
  l_date   DATE;
BEGIN
  l_date := TO_DATE ('12-JAN-2011');
END  ;

If the string you provide does not match the default format, Oracle Database will raise an exception:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
DECLARE
  l_date   DATE;
BEGIN
  l_date := TO_DATE ('January 12 2011');
END;
/
ORA-01858: a non-numeric character was 
found where a numeric was expected

You should not assume that the literal value you provide in your call to TO_DATE matches the default format. What if the format changes over time? Instead, always provide a format mask when converting strings to dates, as in

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
l_date := TO_DATE ('January 12 2011', 
'Month DD YYYY');

Date truncation. Use the TRUNC built-in function to truncate a date to the specified unit of measure. The most common use of TRUNC is TRUNC (date), without any format mask specified. In this case, TRUNC simply sets the time to 00:00:00. You can also use TRUNC to easily obtain the first day in a specified period. Here are some TRUNC examples:

  • Set l_date to today’s date, but with the time set to 00:00:00:
    l_date := TRUNC (SYSDATE);
  • Get the first day of the month for the specified date:
    l_date := TRUNC (SYSDATE, 'MM');
  • Get the first day of the quarter for the specified date:
    l_date := TRUNC (SYSDATE, 'Q');
  • Get the first day of the year for the specified date:
    l_date := TRUNC (SYSDATE, 'Y');

Date arithmetic. Oracle Database enables you to perform arithmetic operations on dates and time stamps in several ways:

  • Add a numeric value to or subtract it from a date, as in SYSDATE + 7; Oracle Database treats the number as the number of days.
  • Add one date to or subtract it from another, as in l_hiredate - SYSDATE.
  • Use a built-in function to “move” a date by a specified number of months or to another date in a week.

Here are some examples of date arithmetic with a date and a number (assume in all cases that the l_date variable has been declared as DATE):

  • Set a local variable to tomorrow’s date:
    l_date := SYSDATE + 1;
  • Move back one hour:
    l_date := SYSDATE - 1/24;
  • Move ahead 10 seconds:
    l_date := SYSDATE + 10 / (60 * 60 * 24);

When you add one date to or subtract it from another, the result is the number of days between the two. As a result, executing this block:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
DECLARE
   l_date1   DATE := SYSDATE;
   l_date2   DATE := SYSDATE + 10;
BEGIN
   DBMS_OUTPUT.put_line (
      l_date2 - l_date1);
   DBMS_OUTPUT.put_line (
      l_date1 - l_date2);
END;

returns the following output:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
10
-10

The following function can be used to compute the age of a person, assuming that the person’s correct birth date is passed as the function’s only argument:

Copied to Clipboard
Error: Could not Copy
Copied to Clipboard
Error: Could not Copy
CREATE OR REPLACE FUNCTION 
your_age (birthdate_in IN DATE)
   RETURN NUMBER
IS
BEGIN
   RETURN SYSDATE - 
          birthdate_in;
END your_age;

Oracle Database offers several built-in functions for shifting a date by the requested amount or finding a date:

  • ADD_MONTHS—Adds the specified number of months to or subtracts it from a date (or a time stamp)
  • NEXT_DAY—Returns the date of the first weekday named in the call to the function
  • LAST_DAY—Returns the date of the last day of the month of the specified date

Here are some examples that use these built-in functions:

  • Move ahead one month:
    l_date := ADD_MONTHS (SYSDATE, 1);
  • Move backward three months:

    l_date := ADD_MONTHS (SYSDATE, -3);

  • Starting with the last day of January, move ahead one month. Starting from a different date, go back one month. Starting with the last day of February, go back one month. Listing 3 shows three different calls to the ADD_MONTHS function along with the results.

     

    Code listing 3: Calls to ADD_MONTHS

    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    BEGIN
       DBMS_OUTPUT.put_line (
          ADD_MONTHS (TO_DATE ('31-jan-2011', 'DD-MON-YYYY'), 1));
       DBMS_OUTPUT.put_line (
          ADD_MONTHS (TO_DATE ('27-feb-2011', 'DD-MON-YYYY'), -1));
       DBMS_OUTPUT.put_line (
          ADD_MONTHS (TO_DATE ('28-feb-2011', 'DD-MON-YYYY'), -1));
    END;

    Here is the output:

    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    28-FEB-11
    27-JAN-11 
    31-JAN-11

    You might be surprised at the third date in Listing 3. The first date (28 February) makes perfect sense. There is no 31st day in February, so Oracle Database returns the last day of the month. The second call to ADD_MONTHS moves the date from 27 February to 27 January: exactly one month’s change. But in the third call to ADD_MONTHS, Oracle Database notices that 28 February is the last day of the month, so it returns the last day of the month specified by the second argument.

  • Find the next Saturday after today’s date:
    Copied to Clipboard
    Error: Could not Copy
    Copied to Clipboard
    Error: Could not Copy
    l_date := NEXT_DAY (SYSDATE, 'SAT');
      -- or
      l_date := NEXT_DAY (SYSDATE, 'SATURDAY');

The second argument must be a day of the week in the date language of your session (specified by NLS_DATE_LANGUAGE), provided as either the full name or the abbreviation. The returned date has the same time component as the date.

Next time: Throwing and catching exceptions

Now that you have a solid foundation in working with key data types such as strings, numbers, dates, and time, the next article of this series will provide an in-depth introduction to exceptions: how they can be raised and how you can handle them.

Dig deeper

Steven Feuerstein

Developer Advocate for PL/SQL

Steven Feuerstein was Oracle Corporation's Developer Advocate for PL/SQL between 2014 and 2021. He is an expert on the Oracle PL/SQL language, having written ten books on PL/SQL, including Oracle PL/SQL Programming and Oracle PL/SQL Best Practices (all published by O'Reilly Media), and currently serving as Senior Advisor for insum Solutions. Steven has been developing software since 1980, spent five years with Oracle back in the "old days" (1987-1992), and was PL/SQL Evangelist for Quest Software (and then Dell) from January 2001 to February 2014 - at which point he returned joyfully to Oracle Corporation. He was one of the original Oracle ACE Directors and writes regularly for Oracle Magazine, which named him the PL/SQL Developer of the Year in both 2002 and 2006. He is also the first recipient of ODTUG's Lifetime Achievement Award (2009).

Show more
Oracle Chatbot
Disconnected