Find/replace using a list

BenMiller

Well-known Member
Joined
Nov 17, 2011
Messages
1,964
Office Version
  1. 365
Platform
  1. Windows
I have a list of close to 13,000 items with detailed descriptions. Many of the words (about 60) within the descriptions need to be changed.
I have a list on a new sheet of the old spelling in column A and the new spelling in column B.
Many of the description cells will contain a bunch of these words, which all need to be replaced with the new ones.
My question is, is it possible to do a find/replace using a cell reference as what to look for and what to replace; and furthermore, can this be done with a range of cells - all the old spellings and all the new spellings.
Below is a sample of my data.


Excel Workbook
ABC
1Old SpellingNew SpellingMaster List
2Milk OCG*MilkOCGLarge bar Milk OCG Dark OCG Dark Caramel
3Dark OCG*DarkOCGSmall square Cookies & Cream Milk OCG
4Cookies & Cream*Cookies&CreamAcetate pack Dark OCG tote bag
5Caramel*CaramelFive piece set Caramel Dark OCG
6Large Custom Mold Dark OCG
7Small round Cookies & Cream Caramel
Sheet3
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
Code:
For i = 1 To 13000
    Range("C" & i).Replace What:=Range("A" & i).Value, Replacement:=Range("B" & i).Value, LookAt:= _
        xlPart, SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False
        
Next

That has only been mildly tested, but it seems to work as long as you start at the top of the page. If your range starts lower, you'll have to adjust the loop's "i" values
 
Upvote 0
See if this does what you want:

<font face=Calibri><SPAN style="color:#00007F">Sub</SPAN> Foo()<br>    <SPAN style="color:#00007F">Dim</SPAN> i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>    <br>        <SPAN style="color:#00007F">For</SPAN> i = 2 <SPAN style="color:#00007F">To</SPAN> Cells(Rows.Count, "A").End(xlUp).Row<br>            Range("C:C").Replace What:=Cells(i, "A").Value, Replacement:=Cells(i, "B").Value, LookAt:= _<br>                xlPart, SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=<SPAN style="color:#00007F">False</SPAN>, _<br>                ReplaceFormat:=False<br>        <SPAN style="color:#00007F">Next</SPAN> i<br>        <br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>

HTH,
 
Upvote 0
See if this does what you want:

<font face=Calibri><SPAN style="color:#00007F">Sub</SPAN> Foo()<br>****<SPAN style="color:#00007F">Dim</SPAN> i <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>****<br>********<SPAN style="color:#00007F">For</SPAN> i = 2 <SPAN style="color:#00007F">To</SPAN> Cells(Rows.Count, "A").End(xlUp).Row<br>************Range("C:C").Replace What:=Cells(i, "A").Value, Replacement:=Cells(i, "B").Value, LookAt:= _<br>****************xlPart, SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=<SPAN style="color:#00007F">False</SPAN>, _<br>****************ReplaceFormat:=False<br>********<SPAN style="color:#00007F">Next</SPAN> i<br>********<br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>

HTH,

This one seemed to work! I noticed you ignore cells A1 and B1, but include C1 - is that correct?
 
Upvote 0
Code:
For i = 1 To 13000
    Range("C" & i).Replace What:=Range("A" & i).Value, Replacement:=Range("B" & i).Value, LookAt:= _
        xlPart, SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
        ReplaceFormat:=False
        
Next

That has only been mildly tested, but it seems to work as long as you start at the top of the page. If your range starts lower, you'll have to adjust the loop's "i" values

This one gave me an error message ...Smitty seems to have solved it though; thanks for the help :)
 
Upvote 0
This one seemed to work! I noticed you ignore cells A1 and B1, but include C1 - is that correct?

Yes, I left out the header rows for the find & replace part, but left in all of column c, because that's the easiest way to reference the entire column.
 
Upvote 0

Forum statistics

Threads
1,215,343
Messages
6,124,404
Members
449,156
Latest member
LSchleppi

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