Extracting the date

amwill

New Member
Joined
Jun 30, 2022
Messages
8
Office Version
  1. 365
Platform
  1. Windows
i have a cell contents that look like this Sep 27th 2023 09:21:00. I use this formula DATEVALUE(MID(E2,5,2)&" "&LEFT(E2,3)&" "&MID(E2,10,4)) to get the date 9/27/2023. However if the days are lower than 10 it will give me a value error. Example: a cell contents with a date like this Sep 6th 2023 10:22:00 gives me the value error. is there a formula i can use that will capture the date no matter the amount of days?
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
If you data is actual dates and not text, then all you will need to do is change the formatting. An alternative if it is Text is to bring it into the Power Query Editor and change the Text to Date/Time and then close and load back to native excel.
 
Upvote 0
the data looks like this Sep 27th 2023 09:21:00 and i would prefer to just create a formula for someone so they don't have to do anything on their side.
 
Upvote 0
What the date looks like when posted here is immaterial because we cannot determine if it is text or numerical in your workbook. Post some samples using XL2BB as that will replicate what is in your workbook. No pictures!
 
Upvote 0
How about this?

EXCEL
AB
1Sep 27th 2023 09:21:009/27/2023
2Sep 6th 2023 10:22:009/6/2023
Sheet2
Cell Formulas
RangeFormula
B1:B2B1=LET(s,DROP(TEXTSPLIT(A1,," "),-1),m,MATCH(INDEX(s,1),{"Jan";"Feb";"Mar";"Apr";"May";"Jun";"Jul";"Aug";"Sep";"Oct";"Nov";"Dec"}),d,LEFT(INDEX(s,2),LEN(INDEX(s,2))-2),DATEVALUE(TEXTJOIN("/",,m,d,INDEX(s,3))))
 
Upvote 0
If you want an alternative that is not sensitive to Regional Settings, try the following
Custom format to your preference

Dates Time.xlsm
AB
1Sep 27th 2023 09:21:0027-Sep-2023 9:21:00
2Sep 6th 2023 10:22:0006-Sep-2023 10:22:00
3
4d
Cell Formulas
RangeFormula
B1:B2B1=DATE(TEXTBEFORE(TEXTAFTER(A1," ",2)," "),MONTH(1&LEFT(A1,3)),IFERROR(--MID(A1,5,2),--(MID(A1,5,1))))+TEXTAFTER(A1," ",3)
 
Upvote 1
Solution
or
Dates Time.xlsm
ABC
1Sep 27th 2023 09:21:0027-Sep-2023 9:21:0027-Sep-2023
2Sep 6th 2023 10:22:0006-Sep-2023 10:22:0006-Sep-2023
3
4d
Cell Formulas
RangeFormula
B1:B2B1=DATE(TEXTBEFORE(TEXTAFTER(A1," ",2)," "),MONTH(1&LEFT(A1,3)),IFERROR(--MID(A1,5,2),--(MID(A1,5,1))))+TEXTAFTER(A1," ",3)
C1:C2C1=DATEVALUE(IFERROR(--MID(A1,5,2),MID(A1,5,1))&"-"&LEFT(A1,3)&"-"&TEXTBEFORE(TEXTAFTER(A1," ",2)," "))
 
Upvote 0
Another approach -- just three function calls and one reference call; works in Excel 2010 and later:
Excel Formula:
=AGGREGATE(14,6,DATEVALUE(SUBSTITUTE(E2,{"st","nd","rd","th"},",")),1)
 
Upvote 0
Another approach -- just three function calls and one reference call; works in Excel 2010 and later:
Excel Formula:
=AGGREGATE(14,6,DATEVALUE(SUBSTITUTE(E2,{"st","nd","rd","th"},",")),1)
I think (but am not 100% sure) that converting text dates written like "Sep 12, 2023" into real dates is locale dependent. Your formula works in my US Locale but I don't think it is internationally universal. If it is, or if the OP's locale accepts it, then this formula would work in his XL365 version of Excel (it uses the same underlying principle that you did)...
Excel Formula:
=TOROW(INT(SUBSTITUTE(E2,{"st","nd","rd","th"},",")),3)
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,217
Members
452,619
Latest member
Shiv1198

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top