TechTip: SQL Current-Date-to-Numeric-Date Comparisons

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times
Dealing with dates within Structured Query Language (SQL) on the iSeries can be somewhat challenging because many iSeries applications store date values in numeric fields while SQL date functions expect DATE or TIMESTAMP values. You can get around this problem by using some simple SQL functions to convert your numeric date into a DATE value or to convert the current DATE value into a numeric value. I'll explain both techniques.

Getting the Date NOW

The first piece of the puzzle is reading the current date in an SQL statement. The key function required to do this is NOW(). This function returns a TIMESTAMP value that represents the current date and time as a value in the format yyyy-mm-dd-hh.mn.ss.msmsms, which represents year, month, day, hour, minute, second, and microsecond. In these examples, you can use the CURRENT_DATE and CURRENT_TIME special registers in place of the NOW() function. The primary reason I used the NOW() function in the examples is because it requires less typing. You can use the value returned by the NOW() function with any of the SQL functions related to date and time measurement. A list of some of these functions is shown in the table below.

Date and Time SQL Functions

Function Name
Description
DATE(timestamp)
Returns the date in the current SQL or job date format
DAY(timestamp)
Returns the day of the month for the specified date
MONTH(timestamp)
Returns the month number for the specified date
YEAR(timestamp)
Returns the four-digit year for the specified date
DAYS(timestamp)
Returns a value that represents the number of days from the date 01/01/0001
TIME(timestamp)
Returns the time in the current SQL or job time format
HOUR(timestamp)
Returns a value that represents the hour of the day for the provided timestamp
MINUTE(timestamp)
Returns a value that represents the minutes for the provided timestamp
SECOND(timestamp)
Returns a value that represents the seconds for the provided timestamp
MICROSECOND(timestamp)
Returns a value that represents the microseconds for the provided timestamp



With the exception of the DATE function, each of these functions will return an integer numeric value. These functions can be used in conjunction with one another to achieve the required result. In code below, I've combined integer numeric values for the MONTH, DAY, and YEAR values to create a numeric date from the timestamp value returned by the NOW function:

SELECT (YEAR(NOW()) * 10000)+(MONTH(NOW()) * 100)+DAY(NOW)


This example creates an 8-digit numeric date in the format yyyymmdd where yyyy represents the four-digit year, mm represents the month, and dd represents the day of the month. In this example, I inserted the year and month values in the proper position within the numeric field by multiplying the year by 10000 and the month by 100. Then, I added the day value to get the complete numeric date field. Using this technique, the value of the date 12/25/2003 would be calculated as shown in Figure 1.

Date:  12/25/2003

Year = 2003, Month = 12, Day=25

(2003 * 10000) + (12 * 100) + 25

Result: 20031225

Figure 1: This example shows how a date value is converted to a numeric value.

The resulting value from this operation can be used for comparison with a date value stored within your database. The sample SQL Select statement shown below selects records from the file ORDERS where DUEDAT is less than the current date.

SELECT * FROM ORDERS 
WHERE DUEDAT < (YEAR(NOW())*10000) + (MONTH(NOW())*100) + 
                DAY(NOW())


There will, however, be times when the current date itself is not part of your criteria, but a given number of days in the past or future is. This is where the DAYS() function comes in. This function will take a given date or timestamp and convert this value to a number of elapsed days from the date 1/1/0001. Once the date is converted to a number of days, the value can be used to perform mathematical operations on the given date. The example below uses the same ORDERS file, but this time, it selects records where the DUEDAT field is between one week ago and one week from now.

SELECT * FROM ORDERS 
WHERE DUEDAT >= (YEAR(DATE(DAYS(NOW())-7))*10000) +     
      (MONTH(DATE(DAYS(NOW())-7))*100) +                
       DAY(DATE(DAYS(NOW())-7)) AND                     
      DUEDAT <= (YEAR(DATE(DAYS(NOW())+7))*10000) +     
      (MONTH(DATE(DAYS(NOW())+7))*100) +                
       DAY(DATE(DAYS(NOW())+7))                         


In this example, once you convert the current date to the days value and subtract or add the required number of days, you convert the value back to a date value using the DATE() function. (I'll examine using the DATE() function to perform other conversions a little later).

Up to this point, the examples have assumed that you are using an 8-digit numeric date field. Some applications use a 7-digit date formatted as cyymmdd where c represents a century flag, yy represents a 2-digit year, mm represents the month number, and dd represents the day of the month. To convert to this date format, you simply subtract 1900 from the year value within the conversion. The code below shows an example from earlier using a 7-digit date format.

SELECT * FROM ORDERS 
WHERE DUEDAT < ((YEAR(NOW())-1900)*10000) + 
               (MONTH(NOW())*100) + DAY(NOW())

Making a DATE()

I've explained how to convert the current date, retrieved from the NOW function, into a numeric date value. Now, I'll do the reverse by converting the numeric date value stored in your database file into a DATE value. This option may be attractive if the SQL data will eventually be displayed or printed, because the resulting value will be a recognizable date.

Earlier, I showed you how to use the DATE function to convert a number-of-days value into a DATE. One of the other uses of this function is to convert a string representation of a date into an actual DATE value. You can use this function, along with the SUBSTR and DIGITS functions, to convert a numeric date. The DIGITS function converts a numeric value into a string. The SUBSTR function allows you to take a defined portion of this string. The following code converts an 8-digit numeric date:

SELECT DATE(SUBSTR(DIGITS(DUEDAT),5,2) || '/' ||
  SUBSTR(DIGITS(DUEDAT),7,2) || '/' ||
  SUBSTR(DIGITS(DUEDAT),1,4))


This example converts the 8-digit numeric date to a string and then breaks apart the year, month, and day portions of the field. Then, it puts those pieces back together along with a slash (/), which is used as the date separator. The string date value is then passed to the DATE() function, which converts the string value to a DATE value. Figure 2 shows graphically how the numeric date is converted.

http://www.mcpressonline.com/articles/images/2002/SQL%20DATE%20Tech%20TipV300.png

Figure 2: This graphic shows how numeric date conversion is done.

Once the date is converted, you can compare the resulting value to any other valid DATE field, including the value resulting from the NOW() function. Here's an example:

SELECT DATE(SUBSTR(DIGITS(DUEDAT),5,2) || '/' ||
  SUBSTR(DIGITS(DUEDAT),7,2) || '/' ||
  SUBSTR(DIGITS(DUEDAT),1,4)) AS DUE_DATE 
FROM ORDERS 
WHERE DATE(NOW()) < DATE(SUBSTR(DIGITS(DUEDAT),5,2) || '/' 
       || SUBSTR(DIGITS(DUEDAT),7,2) || '/' ||
  SUBSTR(DIGITS(DUEDAT),1,4))

Which Is Best?

Now that I've explained two methods for performing the same task, I think it's only fair to look at the pros and cons of each. One shortcoming of converting a numeric value to a date is that, if the numeric date is not a valid date, an SQL error will be generated when attempting conversion. On the other hand, the value of the NOW() function will always be a valid date, so converting this to a numeric value is safer. The numeric date value, however, is not as "reader friendly" as a standard DATE format is.

Now that you have the options, you can decide which method will work best for you.

Mike Faust is MIS Manager for The Lehigh Group in Macungie, Pennsylvania. Mike is also the author of the books The iSeries and AS/400 Programmer's Guide to Cool Things and Active Server Pages Primer from MC Press. You can contact Mike at This email address is being protected from spambots. You need JavaScript enabled to view it..

Mike Faust

Mike Faust is a senior consultant/analyst for Retail Technologies Corporation in Orlando, Florida. Mike is also the author of the books Active Server Pages Primer, The iSeries and AS/400 Programmer's Guide to Cool Things, JavaScript for the Business Developer, and SQL Built-in Functions and Stored Procedures. You can contact Mike at This email address is being protected from spambots. You need JavaScript enabled to view it..


MC Press books written by Mike Faust available now on the MC Press Bookstore.

Active Server Pages Primer Active Server Pages Primer
Learn how to make the most of ASP while creating a fully functional ASP "shopping cart" application.
List Price $79.00

Now On Sale

JavaScript for the Business Developer JavaScript for the Business Developer
Learn how JavaScript can help you create dynamic business applications with Web browser interfaces.
List Price $44.95

Now On Sale

SQL Built-in Functions and Stored Procedures SQL Built-in Functions and Stored Procedures
Unleash the full power of SQL with these highly useful tools.
List Price $49.95

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: