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: Deciphering a Coded Date.
Written by Allen Wyatt (last updated April 14, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Luis receives information in which dates are coded such that years, months, and days are replaced with a single character each. For each field, the numbers 1 to 9 are used and after that letters, from a=10, b=11, ... v=31. For example, the date code 'bc2' means b=11 (the year 2011), c=12 (the month), and day=2. Luis wonders if a function can be devised to replace the coded date with a common date format, such as dd/mm/yyyy.
There are actually several ways you could go about solving this problem. One way is to set up "equivalence tables" within a worksheet, where the left column includes a code character and the right indicates the numeric value that is associated with that character. You could then fashion a formula that uses VLOOKUP to find the values and convert the results into a date.
As an example, create you equivalence table in some unused cells to the right of your data. In my case, I put the table in columns P and Q. In column P I put the code characters, 1 through 9 and a through z. (Make sure you precede the digits 1 through 9 with an apostrophe so they are stored as text rather than as numbers.) In column Q I put the numbers 1 through 35. This entire range (P1:Q35) I then gave a name of DateTable. Here is the formula, then, that will return a decoded date for a coded date stored in cell A1:
=DATE(2000+VLOOKUP(LEFT(A1,1),DateTable,2,0), VLOOKUP(MID(A1,2,1),DateTable,2,0),VLOOKUP(RIGHT(A1,1), DateTable,2,0))
Remember that this is a single, continuous formula. Another technique is to bypass the equivalence tables altogether and instead use a formula to do the conversion. The following is an example that will decode a date in cell A1:
=DATE(2000+FIND(LEFT(A1,1),"123456789abcdefghijklmnopqrstuvwxyz"), FIND(MID(A1,2,1),"123456789abc"),FIND(MID(A1,3,1), "123456789abcdefghijklmnopqrstuv"))
This formula uses the FIND function to translate from the code character to a value, and then these values are used in the DATE function to return the desired date. Another possible formula relies, instead, on character code values to create the date:
=DATE(2000+CODE(MID(A1,1,1))-87+(CODE(MID(A1,1,1))<58)*39,CODE(MID(A1,2,1))-87+(CODE(MID(A1,2,1))<58)*39,CODE(MID(A1,3,1))-87+(CODE(MID(A1,3,1))<58)*39)
Finally, you could create a user-defined function to return the decoded date. The following is just a simple example; it looks at each character and converts it to a numeric value that is then used with the DateSerial function to create an Excel date serial number:
Function DecodeDate(datecode As String) Const X = "123456789abcdefghijklmnopqrstuvwxyz" Dim D As Integer Dim M As Integer Dim Y As Integer Application.Volatile D = InStr(X, Right(datecode, 1)) M = InStr(X, Mid(datecode, 2, 1)) Y = 2000 + InStr(X, Left(datecode, 1)) DecodeDate = DateSerial(Y, M, D) End Function
It should be pointed out, as well, that regardless of the approach you use, there is an inherent flaw in your date codes. The year uses the code values 1 through 9 and a through z. This means that the date code can be one of 35 possible values. When added to the year 2000 (the base year for how you described the code), that means that the maximum year value that can be coded is 2035. Any date after that year will not work with this coding.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12422) 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: Deciphering a Coded Date.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Sometimes it is handy to know how many days are left in the current year. This tip provides a quick formula that ...
Discover MoreNeed to know the number of months between two dates? It's easy to figure out if you use the DATEDIF function.
Discover MoreWhen working with dates, you may need to figure out all the dates on which weeks end in a given year. There are several ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-04-14 05:56:37
Rick Rothstein
Of course what I posted earlier does not work. This is what the UDF (user defined function) should have been...
[code]
Function DecodeDate(Code As String) As Date
Const X = "123456789abcdefghijklmnopqrstuvwxyz"
DecodeDate = 2000 + InStr(X, Left(Code, 1)) & "-" & Format(InStr(X, Mid(Code, 2, 1)), "00") & "-" & Format(InStr(X, Right(Code, 1)), "00")
End Function
[/code]
2018-04-14 05:26:06
Rick Rothstein
Here is another way to write the UDF (user defined function)...
[code]
Function DecodeDate(Code As String) As Date
Const X = "123456789abcdefghijklmnopqrstuvwxyz"
DecodeDate = "20" & InStr(X, Left(Code, 1)) & "-" & InStr(X, Mid(Code, 2, 1)) & "-" & InStr(X, Right(Code, 1))
End Function
[/code]
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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