Close Navigation
Learn more about IBKR accounts
Excel: Converting String Date to Date Type

Excel: Converting String Date to Date Type

Posted October 26, 2023
Sang-Heon Lee
SHLee AI Financial Model

This post demonstrates how to convert a string-formatted date to a Date type using three Excel formulas.

Converting String Date to Date Type

This method is a time-saving solution for processing date columns represented as strings like ’12-Nov-2022′. Crafting an Excel formula to convert these strings to ‘2022-11-12’ each time can be laborious and time-consuming. It’s a common task to handle when preprocessing daily financial data in empirical analysis.

Excel formula

Given a target cell B2 with the value like ’14-Jun-1961′, a first Excel formula to convert this date string to the ‘yyyy-mm-dd’ date format is as follows.

=DATE(
RIGHT(B2,4),
IF(MID(B2,4,3)="Jan","01",IF(MID(B2,4,3)="Feb","02",
IF(MID(B2,4,3)="Mar","03",IF(MID(B2,4,3)="Apr","04",
IF(MID(B2,4,3)="May","05",IF(MID(B2,4,3)="Jun","06",
IF(MID(B2,4,3)="Jul","07",IF(MID(B2,4,3)="Aug","08",
IF(MID(B2,4,3)="Sep","09",IF(MID(B2,4,3)="Oct","10",
IF(MID(B2,4,3)="Nov","11",IF(MID(B2,4,3)="Dec","12",
"")))))))))))),
MID(B2,1,2)
)

A second, more compact Excel formula to achieve the same date conversion is:

=DATE(
RIGHT(B2,4),
MATCH(MID(B2, 4, 3),
    {"Jan","Feb","Mar","Apr","May","Jun",
     "Jul","Aug","Sep","Oct","Nov","Dec"}, 0),
MID(B2,1,2)
)

A third, more robust Excel formula is:

=DATE(
FILTERXML("<root><item>" & SUBSTITUTE(B2, "-", 
    "</item><item>") & "</item></root>", "//item[3]"),
MATCH(FILTERXML("<root><item>" & SUBSTITUTE(B2, "-", 
    "</item><item>") & "</item></root>", "//item[2]"),
    {"Jan","Feb","Mar","Apr","May","Jun",
     "Jul","Aug","Sep","Oct","Nov","Dec"}, 0),
FILTERXML("<root><item>" & SUBSTITUTE(B2, "-", 
    "</item><item>") & "</item></root>", "//item[1]")
)

Result

We can observe the results of the three Excel formulas, and the third formula stands out for its robustness in dealing with variable day lengths, which are often encountered.

Originally posted on SHLee AI Financial Model blog.

Join The Conversation

If you have a general question, it may already be covered in our FAQs. If you have an account-specific question or concern, please reach out to Client Services.

Leave a Reply

Your email address will not be published. Required fields are marked *

Disclosure: Interactive Brokers

Information posted on IBKR Campus that is provided by third-parties does NOT constitute a recommendation that you should contract for the services of that third party. Third-party participants who contribute to IBKR Campus are independent of Interactive Brokers and Interactive Brokers does not make any representations or warranties concerning the services offered, their past or future performance, or the accuracy of the information provided by the third party. Past performance is no guarantee of future results.

This material is from SHLee AI Financial Model and is being posted with its permission. The views expressed in this material are solely those of the author and/or SHLee AI Financial Model and Interactive Brokers is not endorsing or recommending any investment or trading discussed in the material. This material is not and should not be construed as an offer to buy or sell any security. It should not be construed as research or investment advice or a recommendation to buy, sell or hold any security or commodity. This material does not and is not intended to take into account the particular financial conditions, investment objectives or requirements of individual customers. Before acting on this material, you should consider whether it is suitable for your particular circumstances and, as necessary, seek professional advice.

IBKR Campus Newsletters

This website uses cookies to collect usage information in order to offer a better browsing experience. By browsing this site or by clicking on the "ACCEPT COOKIES" button you accept our Cookie Policy.