Replace cell with content from another cell

Nadiasze

New Member
Joined
Nov 13, 2017
Messages
9
Hi!
I have two separate files.
File 1 has text+number content in a column: A1, A2, A3, etc.
File 2 has the same content, and in addition, each one of these values has a corresponding string, in an adjacent column. For example: A1=A1 B1=abc, A2=A2, B2=cde
I want to replace the content of each cell in File 1 with the corresponding content from File 2.
In other words: I am in File 1, and would have to search for the presence of that value in File 2, and replace it with the corresponding content in File 2.
Does anyone know how to do this?
Thank you!
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Do you want to replace the contents of column A in File 1 with the contents of column B in File 2?
 
Upvote 0
Do you want to replace the contents of column A in File 1 with the contents of column B in File 2?

Thanks for the question- In a way, yes, but not quite. Column A in File 1 is not exactly the same as column A in File 2, it is only a subset. So I want to make sure that excel "reads" the content of column A in File 1, Looks for that value in File 2, grabs content from column B in File 2, and comes back to File 1 and replaces the value from Column B (File2) into Column A(File1).
 
Upvote 0
Place this macro in a regular module in File 1. Save File 1 as a macro-enabled file. Make sure that both workbooks are open.
Code:
Sub CompareLists()
    Application.ScreenUpdating = False
    Dim Rng As Range, RngList As Object
    Dim srcWB As Workbook
    Set srcWB = Workbooks("File 2.xlsx")
    Dim desWB As Workbook
    Set desWB = ThisWorkbook
    Set RngList = CreateObject("Scripting.Dictionary")
    For Each Rng In srcWB.Sheets("Sheet1").Range("A1", Range("A" & Rows.Count).End(xlUp))
      If Not RngList.Exists(Rng.Value) Then
        RngList.Add Rng.Value, Nothing
      End If
    Next
    For Each Rng In desWB.Sheets("Sheet1").Range("A1", Range("A" & Rows.Count).End(xlUp))
      If RngList.Exists(Rng.Value) Then
        Rng = srcWB.Sheets("Sheet1").Range("A:A").Find(Rng, LookIn:=xlValues, lookat:=xlWhole).Offset(0, 1)
      End If
    Next
    RngList.RemoveAll
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Hi! Thank you for your answer. I tried this macro (after figuring out how) and it throws an error on line 9. Do you know what that can be? I tried renaming my sheet 1 "sheet1" but it still does not work.


says
Place this macro in a regular module in File 1. Save File 1 as a macro-enabled file. Make sure that both workbooks are open.
Code:
Sub CompareLists()
    Application.ScreenUpdating = False
    Dim Rng As Range, RngList As Object
    Dim srcWB As Workbook
    Set srcWB = Workbooks("File 2.xlsx")
    Dim desWB As Workbook
    Set desWB = ThisWorkbook
    Set RngList = CreateObject("Scripting.Dictionary")
    For Each Rng In srcWB.Sheets("Sheet1").Range("A1", Range("A" & Rows.Count).End(xlUp))
      If Not RngList.Exists(Rng.Value) Then
        RngList.Add Rng.Value, Nothing
      End If
    Next
    For Each Rng In desWB.Sheets("Sheet1").Range("A1", Range("A" & Rows.Count).End(xlUp))
      If RngList.Exists(Rng.Value) Then
        Rng = srcWB.Sheets("Sheet1").Range("A:A").Find(Rng, LookIn:=xlValues, lookat:=xlWhole).Offset(0, 1)
      End If
    Next
    RngList.RemoveAll
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Is workbook 2 named "File 2.xlsx"?
 
Upvote 0
It is always easier to help and test possible solutions if we could work with your actual files. Perhaps you could upload a copy of each file to a free site such as www.box.com. or www.dropbox.com. Once you do that, mark each for 'Sharing' and you will be given a link to each file that you can post here. Include a detailed explanation of what you would like to do referring to specific cells and worksheets. If the workbook contains confidential information, you could replace it with generic data.
 
Upvote 0
@mumps
You forgot to qualify the 2nd range in bot the for next loops.
Code:
Sub CompareLists()
    Application.ScreenUpdating = False
    Dim Rng As Range, RngList As Object
    Dim srcWB As Workbook
    Set srcWB = Workbooks("File 2.xlsx")
    Dim desWB As Workbook
    Set desWB = ThisWorkbook
    Set RngList = CreateObject("Scripting.Dictionary")
    With srcWB.Sheets("Sheet1")
        For Each Rng In .Range("A1", .Range("A" & Rows.Count).End(xlUp))
          If Not RngList.Exists(Rng.Value) Then
            RngList.Add Rng.Value,[COLOR=#0000ff] Rng.Offset(, 1).Value[/COLOR]
          End If
        Next
    End With
    With desWB.Sheets("Sheet1")
        For Each Rng In .Range("A1", .Range("A" & Rows.Count).End(xlUp))
          If RngList.Exists(Rng.Value) Then [COLOR=#0000ff]Rng = RngList.Item(Rng.Value)[/COLOR]
        Next
    End With
    RngList.RemoveAll
    Application.ScreenUpdating = True
End Sub
Also not sure if you're aware, but rather than setting the dictionary item to nothing, you can use it to store (in this case)the Col B value & then pull that out on the 2nd loop, as shown in blue
 
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,255
Members
449,075
Latest member
staticfluids

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