Rearranging text in cell based on special character

rangequestion

Board Regular
Joined
Nov 21, 2016
Messages
62
Hello,

I have multiple date values that look like one of these 2 options:

5/4/2017 12:00:00 AM
20/12/2017 00:00:00

What I'd like to do is only keep the date and convert it in US format. It's in European now. So for the example above I would want:

4/5/2017
12/20/2017

thanks!
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,998
Office Version
  1. 365
Platform
  1. Windows
Have a look at text to columns > Delimited > Next > uncheck all boxes > Date MDY > Finish
 

rangequestion

Board Regular
Joined
Nov 21, 2016
Messages
62
No, that didn't do anything. Plus I need to have it written in a formula rather than using text to columns
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,998
Office Version
  1. 365
Platform
  1. Windows
In that case I'm afraid I can't help, formulae are not my strong point
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows
Hi,

Are those Real Date/Time values (number)? Or are they Text?

If they're Real Date/Time values:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;">5/4/2017 12:00:00 AM</td><td style=";">4/5/2017</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style="text-align: right;;">20/12/2017 00:00:00</td><td style=";">12/20/2017</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet8</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B3</th><td style="text-align:left">=TEXT(<font color="Blue">A3,"m/d/yyyy"</font>)</td></tr></tbody></table></td></tr></table><br />
 

rangequestion

Board Regular
Joined
Nov 21, 2016
Messages
62

ADVERTISEMENT

No, that's the problem, its text and custom format. SO Excel is really hating it right now.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows
No, that's the problem, its text and custom format. SO Excel is really hating it right now.

Hopefully your data are all in the same format as the samples you posted:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style=";">Raw Data</td><td style=";">Formatted as Date</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">5/4/2017 12:00:00 AM</td><td style="text-align: right;;">4/5/2017</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">20/12/2017 00:00:00</td><td style="text-align: right;;">12/20/2017</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet9</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B2</th><td style="text-align:left">=MID(<font color="Blue">SUBSTITUTE(<font color="Red">A2,"/","/"&LEFT(<font color="Green">A2,FIND(<font color="Purple">"/",A2</font>)</font>),2</font>),FIND(<font color="Red">"/",SUBSTITUTE(<font color="Green">A2,"/","/"&LEFT(<font color="Purple">A2,FIND(<font color="Teal">"/",A2</font>)</font>),2</font>)</font>)+1,LEN(<font color="Red">A2</font>)-LEN(<font color="Red">MID(<font color="Green">A2,FIND(<font color="Purple">" ",A2</font>),255</font>)</font>)</font>)+0</td></tr></tbody></table></td></tr></table><br />

Formula copied down, results are converted to Real Dates, just format cells as Date.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows
You're welcome, glad it worked for you.
 

Forum statistics

Threads
1,148,290
Messages
5,745,876
Members
423,983
Latest member
blackworx

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
Top