Replace range if match found

Harshil Mehta

Board Regular
Joined
May 14, 2020
Messages
77
Office Version
  1. 2013
Platform
  1. Windows
The code finds a match for the each cells in Sheet2_Column_1 from Sheet1_Column_1....If a match is found then replace the range in Sheet2_Columns_1 to 5 with Sheet1_Columns_7 to 11.

The blow code only replaces the cell data in Sheet2_Column_1 with Sheet1_Column_7 when the match is found.

Is there any way I could replace all the other column data at once?


VBA Code:
Sub Replace_range()
    Dim Cl As Range
    Dim Dic As Object
    
    Set Dic = CreateObject("scripting.dictionary")
    With Sheets("Sheet1")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            Dic(Cl.Value) = Cl.Offset(, 6)
        Next Cl
    End With
    With Sheets("Sheet2")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            If Dic.exists(Cl.Value) Then
               Cl.Value = Dic(Cl.Value)
               
            End If
        Next Cl
    End With
End Sub
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,443
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Sub Replace_range()
    Dim Cl As Range
    Dim Dic As Object
    
    Set Dic = CreateObject("scripting.dictionary")
    With Sheets("Sheet1")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            Dic(Cl.Value) = Cl.Offset(, 6).Resize(, 5)
        Next Cl
    End With
    With Sheets("Sheet2")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            If Dic.Exists(Cl.Value) Then
               Cl.Resize(, 5).Value = Dic(Cl.Value)
               
            End If
        Next Cl
    End With
End Sub
 
Solution

Harshil Mehta

Board Regular
Joined
May 14, 2020
Messages
77
Office Version
  1. 2013
Platform
  1. Windows
Worked perfectly fine. Thank you so much for the quick response. :love:
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,443
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Harshil Mehta

Board Regular
Joined
May 14, 2020
Messages
77
Office Version
  1. 2013
Platform
  1. Windows
You're welcome & thanks for the feedback.

Hey Fluff, is it possible to edit the code to delete the entire row if match is found?

The below code does not delete the row in one go.

VBA Code:
Sub Delete_Newlyadded()
    
   Dim Cl As Range
    Dim Dic As Object
    
    Set Dic = CreateObject("scripting.dictionary")
    With Sheets("Definition.Temp")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            Dic(Cl.Value) = Cl.Value
        Next Cl
    End With
    With Sheets("New.Temp")
        For Each Cl In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
            If Dic.Exists(Cl.Value) Then
               Cl.EntireRow.Delete
               
            End If
        Next Cl
    End With
            
End Sub
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,443
Office Version
  1. 365
Platform
  1. Windows
As this is a totally different question, it needs a new thread. Thanks
 

Forum statistics

Threads
1,141,400
Messages
5,706,217
Members
421,433
Latest member
yash0468

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
Top