Delimiters in VBA has different result than manual

feni1388

Board Regular
Joined
Feb 19, 2018
Messages
133
Office Version
  1. 2021
Platform
  1. Windows
Hello everyone...

I have a cell (date) that I need to copy to another sheet and use delimiters to separate.
For example: 2024/11/8

if I use delimiter manually, the result is 2024 11 8 which is what I want to achieve.
but when I run VBA it become 11 8 2024

Is there any command that I need to add to achieve the result I want?


VBA Code:
 Columns("E:E").Select
    Application.CutCopyMode = False
    Selection.NumberFormatLocal = "yyyy/m/d"
  
    
    Selection.TextToColumns Destination:=Range("E1"), DataType:=xlDelimited, _
        TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=True, Tab:=False, _
        Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _
        :="/", FieldInfo:=Array(Array(1, 1), Array(2, 1), Array(3, 1)), _
        TrailingMinusNumbers:=True

Thank you in advance.
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Try...

VBA Code:
Selection.TextToColumns Destination:=Range("E1"), DataType:=xlDelimited, _
        TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _
        Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _
        :="/", FieldInfo:=Array(Array(1, 5), Array(2, 1), Array(3, 1)), _
        TrailingMinusNumbers:=True
 
Upvote 0
If Mark's suggestion doesn't work can you please make the cell containing 2024/11/8 the active cell and then show us an image that includes the row references and column references AND the formula bar which should show how that cell appears in the formula bar.
 
Upvote 0
As you will find if you follow Alex's suggestion, changing the cell format (as you did with .NumberFormatLocal = "yyyy/m/d" ) does not change the format of the underlying information in the cell, only what appears in the cell (check the formula bar as Alex mentioned)

If you want to use Text to Columns I think that you will have to use multiple passes. It is unclear from your sample date which part is month and which part is day (8 and 11 can both be day or month) so this code may need a further tweak but I think will get you close.

VBA Code:
Sub Testing()
  With Columns("E")
    .TextToColumns Destination:=.Cells(1, 3), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 1), Array(2, 9), Array(3, 9))
    .TextToColumns Destination:=.Cells(1, 2), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 9), Array(2, 1), Array(3, 9))
    .TextToColumns Destination:=.Cells(1, 1), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 9), Array(2, 9), Array(3, 1))
    .NumberFormat = "0"
  End With
End Sub
 
Upvote 0
Solution
Try...

VBA Code:
Selection.TextToColumns Destination:=Range("E1"), DataType:=xlDelimited, _
        TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _
        Semicolon:=False, Comma:=False, Space:=False, Other:=True, OtherChar _
        :="/", FieldInfo:=Array(Array(1, 5), Array(2, 1), Array(3, 1)), _
        TrailingMinusNumbers:=True
I tried it already, but it didn't work.
It still gave me the same result as before.
I used the code that Peter_SSs gave me and it solved my problem.
Thank you for your suggestion.
 
Upvote 0
If Mark's suggestion doesn't work can you please make the cell containing 2024/11/8 the active cell and then show us an image that includes the row references and column references AND the formula bar which should show how that cell appears in the formula bar.

I used the code that Peter_SSs gave me and it worked great already.
Thank you.
 
Upvote 0
As you will find if you follow Alex's suggestion, changing the cell format (as you did with .NumberFormatLocal = "yyyy/m/d" ) does not change the format of the underlying information in the cell, only what appears in the cell (check the formula bar as Alex mentioned)

If you want to use Text to Columns I think that you will have to use multiple passes. It is unclear from your sample date which part is month and which part is day (8 and 11 can both be day or month) so this code may need a further tweak but I think will get you close.

VBA Code:
Sub Testing()
  With Columns("E")
    .TextToColumns Destination:=.Cells(1, 3), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 1), Array(2, 9), Array(3, 9))
    .TextToColumns Destination:=.Cells(1, 2), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 9), Array(2, 1), Array(3, 9))
    .TextToColumns Destination:=.Cells(1, 1), DataType:=xlDelimited, Other:=True, OtherChar:="/", FieldInfo:=Array(Array(1, 9), Array(2, 9), Array(3, 1))
    .NumberFormat = "0"
  End With
End Sub
Thank you..... your code works perfectly.
I just changed it a little bit as 11 is for November.
 
Upvote 0
You're welcome. Glad you could adjust as required. Thanks for the follow-up. :)
 
Upvote 0

Forum statistics

Threads
1,224,885
Messages
6,181,582
Members
453,055
Latest member
cope7895

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