Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Converting Coded Dates into Real Dates.
Written by Allen Wyatt (last updated September 2, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Luis receives dates in the format "04C18" 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. This approach is best to use if the letters representing the months are not consecutive or if they are a decreasing sequence.
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 (7014) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Converting Coded Dates into Real Dates.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
If you use Excel to maintain a collection of data, you may need to find information in one column based on information in ...
Discover MoreExcel is great when it comes to working with dates and times. You can even do math on dates. One such easy manipulation ...
Discover MoreWant to find out how many of a particular weekday occurs within a given month? Here's how you can find the desired ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-07-06 10:12:26
J. Woolley
@Tomek
See my comment here: https://excelribbon.tips.net/T009392
2024-07-05 14:15:34
@J. Woolley:
Yes, it may be a problem, but for such cases you should use four-digit year.
I vaguely remember that there was a setting somewhere to shift the range of years Excel uses for two-digit year parsing. If you know this, please reply, otherwise I will look for it when I have more time.
2024-07-04 15:03:58
J. Woolley
The Tip mentions the DATEVALUE function. Be aware that DATEVALUE thinks the 21st century ends after 2029, so DATEVALUE("12/25/30") returns 12/25/1930 instead of 12/25/2030 as might be expected. This could be a problem for the current and future decades. For more on this subject, see my comment here: https://excelribbon.tips.net/T009392
2023-09-02 12:23:11
Mark
Again I'll suggest that Power Query might be a good option for this data import. In it you can easily process the received format into a valid date format.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments