How to shorten this code using loop?

eyenanie

New Member
Joined
Jul 15, 2018
Messages
2
i have this format 08:4516:45 where both the time in and time out of an employee is inside a cell (no space) . I want to split them using column to text where only 08:45 is seen. And since i dont really know how vba works, i always use record macro that gave me the code below.

The problem is, it's so long because i have to do it on 31 columns (starting with column D and ends with column AH). It also takes time to run.

Can someone please help me how to shorten this code using loop? :(

Code:
Columns("D:D").Select
    Selection.TextToColumns Destination:=Range("D1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True

    Columns("E:E").Select
    Selection.TextToColumns Destination:=Range("E1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True

    Columns("F:F").Select
    Selection.TextToColumns Destination:=Range("F1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True

    Columns("G:G").Select
    Selection.TextToColumns Destination:=Range("G1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("H:H").Select
    Selection.TextToColumns Destination:=Range("H1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("I:I").Select
    Selection.TextToColumns Destination:=Range("I1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("J:J").Select
    Selection.TextToColumns Destination:=Range("J1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("K:K").Select
    Selection.TextToColumns Destination:=Range("K1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("L:L").Select
    Selection.TextToColumns Destination:=Range("L1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("M:M").Select
    Selection.TextToColumns Destination:=Range("M1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("N:N").Select
    Selection.TextToColumns Destination:=Range("N1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("O:O").Select
    Selection.TextToColumns Destination:=Range("O1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("P:P").Select
    Selection.TextToColumns Destination:=Range("P1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("Q:Q").Select
    Selection.TextToColumns Destination:=Range("Q1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("R:R").Select
    Selection.TextToColumns Destination:=Range("R1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("S:S").Select
    Selection.TextToColumns Destination:=Range("S1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("T:T").Select
    Selection.TextToColumns Destination:=Range("T1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("U:U").Select
    Selection.TextToColumns Destination:=Range("U1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("V:V").Select
    Selection.TextToColumns Destination:=Range("V1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("W:W").Select
    Selection.TextToColumns Destination:=Range("W1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("X:X").Select
    Selection.TextToColumns Destination:=Range("X1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("Y:Y").Select
    Selection.TextToColumns Destination:=Range("Y1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("Z:Z").Select
    Selection.TextToColumns Destination:=Range("Z1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AA:AA").Select
    Selection.TextToColumns Destination:=Range("AA1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AB:AB").Select
    Selection.TextToColumns Destination:=Range("AB1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AC:AC").Select
    Selection.TextToColumns Destination:=Range("AC1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AD:AD").Select
    Selection.TextToColumns Destination:=Range("AD1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AE:AE").Select
    Selection.TextToColumns Destination:=Range("AE1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AF:AF").Select
    Selection.TextToColumns Destination:=Range("AF1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AG:AG").Select
    Selection.TextToColumns Destination:=Range("AG1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Columns("AH:AH").Select
    Selection.TextToColumns Destination:=Range("AH1"), DataType:=xlFixedWidth, _
        FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Maybe (untested)

Code:
Sub TxtToCols()
    Dim i As Long
    Application.ScreenUpdating = False
    
    For i = 4 To 34
        Columns(i).TextToColumns Destination:=Cells(1, i), DataType:=xlFixedWidth, _
                                 FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Next
    
    Application.ScreenUpdating = True

End Sub
 
Upvote 0
Or possibly maybe. (I am assuming that you have a header row)...

Code:
Sub TxtToCols2()
Dim rngData As Range, lr As Long

lr = Range("D" & Rows.Count).End(xlUp).Row
Set rngData = Range("AD2:AH" & lr)
    rngData = Evaluate("if(Row(2:" & lr & "),left(" & rngData.Address & ",5))")
End Sub
 
Upvote 0
It worked! ? Thank you so much. I dont have a header row but i appreciate your thoughtfulness. Thank youu

Maybe (untested)

Code:
Sub TxtToCols()
    Dim i As Long
    Application.ScreenUpdating = False
    
    For i = 4 To 34
        Columns(i).TextToColumns Destination:=Cells(1, i), DataType:=xlFixedWidth, _
                                 FieldInfo:=Array(Array(0, 1), Array(5, 9)), TrailingMinusNumbers:=True
    Next
    
    Application.ScreenUpdating = True

End Sub
 
Upvote 0
If you don't have a header row then try the code amended below...

Code:
Sub TxtToCols2()
Dim rngData As Range, lr As Long

lr = Range("D" & Rows.Count).End(xlUp).Row
Set rngData = Range("AD1:AH" & lr)
    rngData = Evaluate("if(Row(1:" & lr & "),left(" & rngData.Address & ",5))")
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,221
Messages
6,177,217
Members
452,764
Latest member
Mark1963

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