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
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:
Listing 1 includes example variables whose declaration is based on these data types.
Code listing 1: Declaring DATE, TIMESTAMP, and INTERVAL variables
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:
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
BEGIN
DBMS_OUTPUT.put_line (SYSDATE);
DBMS_OUTPUT.put_line (SYSTIMESTAMP);
DBMS_OUTPUT.put_line (SYSDATE - SYSTIMESTAMP);
END;
/
Here is the output:
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:
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
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
BEGIN
DBMS_OUTPUT.put_line (
TO_CHAR (SYSDATE,
'Day, DDth Month YYYY',
'NLS_DATE_LANGUAGE=Spanish'));
END;
/
Domingo , 07TH Agosto 2011
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:
TO_CHAR (SYSDATE, 'Q')
TO_CHAR (SYSDATE, 'DDD')
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:
EXTRACT (YEAR FROM SYSDATE)
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:
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:
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
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:
l_date := TRUNC (SYSDATE);
l_date := TRUNC (SYSDATE, 'MM');
l_date := TRUNC (SYSDATE, 'Q');
l_date := TRUNC (SYSDATE, 'Y');
Date arithmetic. Oracle Database enables you to perform arithmetic operations on dates and time stamps in several ways:
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):
l_date := SYSDATE + 1;
l_date := SYSDATE - 1/24;
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:
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:
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:
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:
Here are some examples that use these built-in functions:
l_date := ADD_MONTHS (SYSDATE, 1);
l_date := ADD_MONTHS (SYSDATE, -3);
Code listing 3: Calls to ADD_MONTHS
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:
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.
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 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).