Macro: if column contains any number of possible strings, add zeros to front of number in that column

sndameron

New Member
Joined
Sep 21, 2014
Messages
30
I have a column that contains numbers whose leading zeros disappeared thanks to importing into excel. I want to reduce the number of steps this involves so I really don't want to open it in some other program to fix it then import. I'm already running a macro on this for something else, and would love to just add a little bit of script into it to fix this issue. So, I need a macro written that will look at the column with say a header name of ID. If the adjacent column called NAME is any of the following text: apple, orange, banana, blueberry, then add zeros to the beginning of the numbers of column ID so that its total digits is 9. If it does not match criteria, keep it at whatever number is already in the adjacent cell. It would be great if it could just replace the number in the ID column, but I'm okay if it gets moved to another column if that makes it simpler. For example:
[TABLE="width: 261"]
<tbody>[TR]
[TD="class: xl116, width: 87"]ID[/TD]
[TD="class: xl117, width: 87"]NAME[/TD]
[TD="class: xl117, width: 87"]CONVERT TO[/TD]
[/TR]
[TR]
[TD="class: xl116"]1234[/TD]
[TD="class: xl117"]banana[/TD]
[TD="class: xl117"]000001234[/TD]
[/TR]
[TR]
[TD="class: xl116"]45[/TD]
[TD="class: xl117"]cucumber[/TD]
[TD="class: xl117"]45[/TD]
[/TR]
[TR]
[TD="class: xl116"]9876[/TD]
[TD="class: xl117"]orange[/TD]
[TD="class: xl117"]000009876[/TD]
[/TR]
[TR]
[TD="class: xl116"]343[/TD]
[TD="class: xl117"]apple[/TD]
[TD="class: xl117"]000000343[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Try this :
Code:
Sub FT()
Dim ray: ray = Array("apple", "banana", "orange")
Dim rng As Range: Set rng = Range([B1], Cells(Rows.Count, "B").End(xlUp))
Rng.AutoFilter Field:=1, Criteria1:=ray, Operator:=xlFilterValues
rng.SpecialCells(xlCellTypeVisible).NumberFormat = "000000000"
rng.AutoFilter
End Sub
 
Last edited:
Upvote 0
Amended :
Code:
Sub FT()
Dim ray: ray = Array("apple", "banana", "orange")
Dim rng As Range: Set rng = Range([B1], Cells(Rows.Count, "B").End(xlUp))
Rng.AutoFilter Field:=1, Criteria1:=ray, Operator:=xlFilterValues
rng.Offset(0,-1).SpecialCells(xlCellTypeVisible).NumberFormat = "000000000"
rng.AutoFilter
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,313
Members
452,634
Latest member
cpostell

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