Converting dates

kristell

New Member
Joined
Dec 12, 2014
Messages
33
Office Version
  1. 365
Platform
  1. Windows
Can you please help me? I am having to daily download in CSV some information from a booking site. Unfortunately they are dates and times in USA format - so the 'days' are coming out in the middle. That isn't a big problem as I can change with the formatting, however - when I first download they look like this:
11/29/22 9:00 AM
11/29/22 9:00 AM
11/28/22 2:00 PM
11/21/22 2:00 PM
11/24/22 9:00 AM
11/24/22 9:00 AM
12/05/2022 14:00​
11/24/22 9:00 AM
12/05/2022 14:00​
11/21/22 2:00 PM
11/29/22 9:00 AM
12/01/2022 09:00​
11/23/22 2:00 PM
11/25/22 2:00 PM
11/29/22 9:00 AM
11/21/22 2:00 PM
11/21/22 2:00 PM

This is just a sample but there are around 600 rows

How can I get those on the right to change to be the same as those on the left - or vice versa?

I have tried using various formats - but it never works so they are all the same. I just need to be able to sort them, but it isn't working.

The ones on the left have come in as format 'General' and those on the left as Custom dd/mm/yyy hh:mm (which is wrong anyway as it is the month first). If I try changing those on the left to the same it makes no difference. If I change those on the right to General it changes to 44573.375. If I then try changing again to the date format it just goes back to what it was.

Am pulling my hair out - any ideas would be very much welcomed. If I could also convert all the dates/times to UK that would be an added bonus!

I am using a desktop version of Excel Microsoft® Excel® for Microsoft 365 MSO (Version 2209 Build 16.0.15629.20196) 32-bit
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
An overkill formula:
Excel Formula:
=TEXT(LEFT(A1,2)&"/"&MID(A1,4,2)&"/"&IF(FIND(" ",A1,5)-FIND("/",A1,5)=3,"20"&MID(A1,7,2),MID(A1,7,2)),"dd/mm/yyyy")&" "&TEXT(IF(RIGHT(A1,1)="M",IF(RIGHT(A1,2)="AM",TRIM(MID(A1,FIND(" ",A1,5),6)),MOD(12+INT(LEFT(TRIM(MID(A1,FIND(" ",A1,5),6)),2)),24)&RIGHT(TRIM(MID(A1,FIND(" ",A1,5),6)),3)),IF(LEN(TRIM(RIGHT(A1,6)))=5,0&TRIM(RIGHT(A1,6)),TRIM(RIGHT(A1,6)))),"hh:mm")
 
Upvote 0
Heres another:

=IF(ISNUMBER(A1),DATE(YEAR(A1),DAY(A1),MONTH(A1))+MOD(A1,1),0+(MID(A1,4,3)&REPLACE(A1,3,3,"")))
 
Upvote 0
Solution
An overkill formula:
Excel Formula:
=TEXT(LEFT(A1,2)&"/"&MID(A1,4,2)&"/"&IF(FIND(" ",A1,5)-FIND("/",A1,5)=3,"20"&MID(A1,7,2),MID(A1,7,2)),"dd/mm/yyyy")&" "&TEXT(IF(RIGHT(A1,1)="M",IF(RIGHT(A1,2)="AM",TRIM(MID(A1,FIND(" ",A1,5),6)),MOD(12+INT(LEFT(TRIM(MID(A1,FIND(" ",A1,5),6)),2)),24)&RIGHT(TRIM(MID(A1,FIND(" ",A1,5),6)),3)),IF(LEN(TRIM(RIGHT(A1,6)))=5,0&TRIM(RIGHT(A1,6)),TRIM(RIGHT(A1,6)))),"hh:mm")
I went with the other one which was simpler but really appreciate your response
 
Upvote 0

Forum statistics

Threads
1,214,832
Messages
6,121,841
Members
449,051
Latest member
excelquestion515

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