Written by Allen Wyatt (last updated June 1, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Converting Coded Dates into Real Dates.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Many businesses need to know when the last business day of the month occurs. This tip discusses several ways you can ...
Discover MoreExcel allows you to perform all sorts of calculations using dates. A good example of this is using a formula to figure ...
Discover MoreNeed to know the number of months between two dates? It's easy to figure out if you use the DATEDIF function.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-06-09 16:22:39
J. Woolley
The following Microsoft article discusses Excel dates:
https://support.microsoft.com/en-us/office/change-the-date-system-format-or-two-digit-year-interpretation-aaa2159b-4ae8-4651-8bce-d4707bc9fb9f
Under the heading "Change the way two-digit years are interpreted," some issues are worth considering (with respect to Excel 365 as of June 2022 and region "United States"):
For the Windows 10 procedure to "change the way two-digit years are interpreted for all Windows programs that you have installed," in step 1 you should search for "region" instead of "control panel" and select Region, then skip steps 2 and 3 and continue with step 4. Let's assume you "change the upper limit for the century" to 2049 (for example). Now when you type 12/25/42 into a cell the date will be 12/25/2042 and typing 12/25/52 will produce 12/25/1952. However, Excel's DATEVALUE function ignores the Windows Region Calendar; it thinks the 21st century ends after 2029, so =DATEVALUE("12/25/42") returns 12/25/1942 instead of 12/25/2042 as desired. This could be a problem for the current and future decades.
It is worth noting that VBA's DateValue function recognizes a change to the century upper limit appropriately, so DateValue("12/25/42") returns 12/25/2042 (for this example).
My Excel Toolbox includes the DATEVALUE2 function to address this issue. Here is an abbreviated version:
Function DATEVALUE2(Date_Text As String) As Date
DATEVALUE2 = DateValue(Date_Text)
End Function
See https://sites.google.com/view/MyExcelToolbox/
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 © 2023 Sharon Parq Associates, Inc.
Comments