Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Converting Coded Dates into Real Dates

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Converting Coded Dates into Real Dates.

Luis receives dates in the format "04A09" where the first two digits are the day, the letter in the middle is the month (A is January, B is February, C is March, etc.), and the last two digits are the year. He needs to transform these coded dates into regular date values that he can work with in Excel.

The biggest thing that makes this date format non-standard is the use of the alphabetic character for the month. So, the first thing to do is to figure out how to convert that character into a numeric month. This is where the CODE function can be helpful; it returns the ASCII code for the character. The letter A returns the value 65, B returns 66, and so on. So, all you need to do to convert the letters into the numbers 1 through 12 is to use something like this:

=CODE(UPPER(MID(A1,3,1)))-64

The UPPER function is used to convert the month character to uppercase, just in case the code allows lowercase letters for months.

Another way of converting the months is to use the FIND function, in this manner:

=FIND(UPPER(MID(A1,3,1)),"ABCDEFGHIJKL",1)

This technique finds the character within the alphabetic string and returns the offset within that string, 1 through 12.

Either method of converting the months can then be used inside a DATE function to return a date based upon a year, month, and day. This example uses the CODE method, but you could just as easily use the FIND method:

=DATE(2000+RIGHT(A1,2),CODE(UPPER(MID(A1,3,1)))-64,LEFT(A1,2))

If there is the possibility that the coded dates could include some dates prior to 2000, then using the DATEVALUE function to put together the date will produce more accurate results:

=DATEVALUE(CODE(UPPER(MID(A1,3,1)))-64&"/"&LEFT(A1,2)&"/"&RIGHT(A1,2))

If you use the DATEVALUE approach, understand that the formula returns a date serial number and that you will need to format the cell to display the date as you would like it displayed.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7163) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Converting Coded Dates into Real Dates.

Related Tips:

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.