Removing first character and last 3 in range

figuare9

Board Regular
Joined
Oct 23, 2017
Messages
118
I'm a bit stumped trying to remove some characters from a string with VBA.

I can sort of get it working with a formula using =Left... but I can only get one side working, but I'd prefer to use a command button to set it up, so I'd like to accomplish it in vba.


In range AJ1:AJ200 I have a several different wages.

E.g.
$80.70/hr
$69.70/hr
$60.525/hr
$60.22/hr
$53.12/hr
$52.275/hr
$48.30/hr
$40.35/hr
$34.85/hr
$24.15/hr
$17.25/hr
$15.25/hr

<colgroup><col></colgroup><tbody>
</tbody>


Some have 3 decimal points, some have 2. However, all of them have "/hr" at the end, and "$" in the beginning.

I'd like to remove all "$" & "/hr" from the entire range in VBA and convert these to a number.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
You could use a formula: =0+LEFT(RIGHT(AJ1,LEN(AJ1)-1),LEN(RIGHT(AJ1,LEN(AJ1)-4))) and fill down
Or VBA per this formula:

Code:
Sub remove()
Dim LR As Long, i As Integer
LR = Cells(Rows.Count, "AJ").End(xlUp).Row
For i = 1 To LR
  Cells(i, 36) = 0 + Left(Right(Range("AJ" & i), Len(Range("AJ" & i)) - 1), Len(Right(Range("AJ" & i), Len(Range("AJ" & i)) - 4)))
Next
End Sub
 
Last edited:
Upvote 0
You could use a formula: =0+LEFT(RIGHT(AJ1,LEN(AJ1)-1),LEN(RIGHT(AJ1,LEN(AJ1)-4))) and fill down
Or VBA per this formula:

Code:
Sub remove()
Dim LR As Long, i As Integer
LR = Cells(Rows.Count, "AJ").End(xlUp).Row
For i = 1 To LR
  Cells(i, 36) = 0 + Left(Right(Range("AJ" & i), Len(Range("AJ" & i)) - 1), Len(Right(Range("AJ" & i), Len(Range("AJ" & i)) - 4)))
Next
End Sub

That was quick! This forum never disappoints... I love it here!

Thanks Kweaver!
 
Upvote 0
Instead of doing it one row at a time, what about processing the whole column at once (twice)?

Rich (BB code):
Sub Remove_Characters()
  With Range("AJ1", Range("AJ" & Rows.Count).End(xlUp))
    .Replace What:="$", Replacement:="", LookAt:=xlPart
    .Replace What:="/*", Replacement:="", LookAt:=xlPart
  End With
End Sub

If you did want a formula approach, here is a simpler one:

=MID(AJ1,2,LEN(AJ1)-4)+0
 
Last edited:
Upvote 0
Instead of doing it one row at a time, what about processing the whole column at once (twice)?

Rich (BB code):
Sub Remove_Characters()
  With Range("AJ1", Range("AJ" & Rows.Count).End(xlUp))
    .Replace What:="$", Replacement:="", LookAt:=xlPart
    .Replace What:="/*", Replacement:="", LookAt:=xlPart
  End With
End Sub

If you did want a formula approach, here is a simpler one:

=MID(AJ1,2,LEN(AJ1)-4)+0


That's great! Thank you. That might actually come in handy! I appreciate it
 
Upvote 0
That's great! Thank you. That might actually come in handy! I appreciate it
You're welcome. :)

The previous code is probably easier to follow, but you could use the formula idea in code to do it with one less code line (& this time only processing the column once). :cool:

Rich (BB code):
Sub Remove_Characters_v2()
  With Range("AJ1", Range("AJ" & Rows.Count).End(xlUp))
    .Value = Evaluate(Replace("if(#="""","""",mid(#,2,len(#)-4))", "#", .Address))
  End With
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,651
Messages
6,120,739
Members
448,989
Latest member
mariah3

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