Macro/Function to Replace Multiple Strings of Text

nyastrab

New Member
Joined
Jul 29, 2009
Messages
3
Hi -- I need to normalize a bunch of company names. By 'normalize' i mean to remove things like "Ltd", "Inc", "LLP", "LP", "The ", "&", etc. The function needs to ignore case and strip out punctuation.

I tried recording a macro (below), but it cuts out if there are too many rows on the file.

Can anyone help me set something up for this? Thanks.
--------
Selection.Replace What:="The ", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Selection.Replace What:=".", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Selection.Replace What:=",", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Selection.Replace What:=":", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Selection.Replace What:=";", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
Selection.Replace What:="'", Replacement:="", LookAt:=xlPart, _
SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
ReplaceFormat:=False
 

Excel Facts

What is the last column in Excel?
Excel columns run from A to Z, AA to AZ, AAA to XFD. The last column is XFD.
This is the macro I would use.

Sub CleanUp()
Dim c As Range
For Each c In Selection.Cells
c.Value = Replace(c.Value, "Ltd", "")
c.Value = Replace(c.Value, "Inc", "")
'and so on
c.Value = Trim(c.Value)
Next c
End Sub

As you can see you will need to extend it by adding additional Replace statements for each of the items you need to eliminate.

Hope this helped,
Rolf
 
Upvote 0
nyastrab

Not quite sure what you mean by "it cuts out if there are too many rows on the file", but you could see if this more compact code is any use to you. Suggest you test on a copy of your workbook.

<font face=Courier New><br><SPAN style="color:#00007F">Sub</SPAN> ReplaceStrings()<br>    <SPAN style="color:#00007F">Dim</SPAN> DoNotWant<br>    <SPAN style="color:#00007F">Dim</SPAN> i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>    <br>    DoNotWant = Array("The ", ".", ",", ":", ";", "'", "Ltd", "Inc") <SPAN style="color:#007F00">'<-- extend as needed</SPAN><br>    Application.ScreenUpdating = <SPAN style="color:#00007F">False</SPAN><br>    <SPAN style="color:#00007F">With</SPAN> Columns("A") <SPAN style="color:#007F00">'<-- adjust to suit your column</SPAN><br>        <SPAN style="color:#00007F">For</SPAN> i = 0 <SPAN style="color:#00007F">To</SPAN> <SPAN style="color:#00007F">UBound</SPAN>(DoNotWant)<br>            .Replace What:=DoNotWant(i), Replacement:="", LookAt:=xlPart, _<br>                SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=<SPAN style="color:#00007F">False</SPAN>, _<br>                ReplaceFormat:=False<br>        <SPAN style="color:#00007F">Next</SPAN> i<br>    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN><br>    Application.ScreenUpdating = <SPAN style="color:#00007F">True</SPAN><br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br><br></FONT>
 
Upvote 0

Forum statistics

Threads
1,214,591
Messages
6,120,431
Members
448,961
Latest member
nzskater

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