Trimming left

chandler1983

New Member
Joined
Jan 5, 2014
Messages
10
Hi Everyone

I think this will be a simple one, but I cannot find exactly what I need.

I need to trim values (all text) in column H to 8 characters. I can't seem to do this in VBA.
I tried on the front end but I can't use this as the clear we have wipes it out.

I just need it to keep the LEFT 8 and drop anything left.
 

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.

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
10,648
Tryt:
Code:
Sub TrimVals()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim rng As Range
    For Each rng In Range("H2:H" & LastRow)
        rng = Left(rng, 8)
    Next rng
    Application.ScreenUpdating = True
End Sub
 

Marcílio_Lobão

Well-known Member
Joined
Oct 7, 2013
Messages
789
Office Version
  1. 2007
Platform
  1. Windows

ADVERTISEMENT

chandler1983,

Glad to have helped you.

Thanks for the feedback.
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
37,557
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
Tryt:
Code:
Sub TrimVals()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim rng As Range
    For Each rng In Range("H2:H" & LastRow)
        rng = Left(rng, 8)
    Next rng
    Application.ScreenUpdating = True
End Sub
I know the OP has decided to use the manual version of Text To Columns, but it can also be used to create a one-liner macro...
Code:
[table="width: 500"]
[tr]
	[td]Sub GetLeftEight()
  Range("H2", Cells(Rows.Count, "H").End(xlUp)).TextToColumns , xlFixedWidth, FieldInfo:=Array(Array(0, 1), Array(8, 9))
End Sub[/td]
[/tr]
[/table]
 

mumps

Well-known Member
Joined
Apr 11, 2012
Messages
10,648

ADVERTISEMENT

Thanks, Rick. I was looking for a one-liner but I couldn't figure it out. :) Would you mind explaining how
Code:
FieldInfo:=Array(Array(0, 1), Array(8, 9))
works? Many thanks.
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
37,557
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows
Thanks, Rick. I was looking for a one-liner but I couldn't figure it out. :) Would you mind explaining how
Code:
FieldInfo:=Array(Array(0, 1), Array(8, 9))
works? Many thanks.
The first number in the array is the starting position for the field and the second number is the equivalent value for the option for that field (1 is General, 9 is Skip Column... the other options are for text and date order); however, I never work those numbers out for myself, rather, what I do is turn on the macro recorder and perform the action manually and I let it generate the FieldInfo for me.
 

Forum statistics

Threads
1,148,294
Messages
5,745,942
Members
423,985
Latest member
sayed manzar

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