Summary

To convert a date string to a datetime (date with time) you can parse the text into separate components then build a proper datetime. In the example shown, we are using several functions to perform this task, including DATEVALUE, TIMEVALUE, LEFT and MID. In the worksheet shown, to extract the date, the formula in C5 is:

=DATEVALUE(LEFT(B5,10))

To extract the time, the formula in D5 is:

=TIMEVALUE(MID(B5,12,8))

To assemble a datetime, the formula in E5 is:

=C5+D5

Generic formula

=LEFT(date,10)+MID(date,12,8)

Explanation 

When date information from other systems is pasted or imported to Excel, it may not be recognized as a proper date or time. Instead, Excel may interpret this information as a text or string value only. In this example, the goal is to extract valid date and time information from a text string and convert that information into a datetime. It is important to understand that Excel dates and Excel times are numbers so at a high level, the main task is to convert a text value to the appropriate numeric value.

Date

To get the date, we extract the first 10 characters of the value with the LEFT function:

LEFT(B5,10) // returns "2015-03-01"

The result is text, so to get Excel to interpret as a date, we wrap LEFT in DATEVALUE, which converts the text into a proper Excel date.

Time

To get the time, we extract 8 characters from the middle of the text with the MID function:

MID(B5,12,8) // returns "12:28:45"

Again, the result is text. To get Excel to interpret this value as time, we wrap MID in TIMEVALUE, which converts the text into a proper Excel time.

Datetime

To get a final datetime, we just add the date value to the time value. The formula in E5 is:

=C5+D5

Once you have a valid datetime, use custom number formatting to display the value as desired.

All in one formula

Although this example extracts the date and time separately for clarity, you can combine formulas if you like. The following formula extracts the date and time, and adds them together in one step:

=LEFT(date,10)+MID(date,12,8)

Note that DATEVALUE and TIMEVALUE aren't necessary in this case because the math operation (+) causes Excel to automatically coerce the text values to numbers.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.