Question about Data Consolidation

jakecc

New Member
Joined
Feb 22, 2016
Messages
15
To whom it may concern,

Hello, my name is Jake, and I've been presented with a large task in Excel. I have two sheets that I'm working with; the first sheet has 1436 rows and the second sheet has 2548 rows. Essentially, my task is this:

If any of the values within sheet 1, column a, are present within sheet 2, column a, then...

I must take the neighboring -right- cell within sheet 1 and place that value somewhere within the corresponding row in sheet 2.

Hypothetical:

Sheet 1, cell A1, matches sheet 2, cell a15. I now must take sheet 1, cell b1, and insert that cell somewhere within sheet 2, row 15.


If there's a way to do this AUTOMATICALLY, I'd be most grateful to learn how to do so!!!!!!

Thanks,

Jake
 

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.
In which column in Sheet2 do you want to insert the copied cell?
 
Upvote 0
Sheet 1, cell A1, matches sheet 2, cell a15. I now must take sheet 1, cell b1, and insert that cell somewhere within sheet 2, row 15.
Can you describe the "somewhere within sheet 2, row 15" part of your request? Is there as specific column it should go in? If no, is there a header cell in Row 1 under which it should go? If not, should it go after the last filled cell in the found row? Something else?
 
Upvote 0
Can you describe the "somewhere within sheet 2, row 15" part of your request? Is there as specific column it should go in? If no, is there a header cell in Row 1 under which it should go? If not, should it go after the last filled cell in the found row? Something else?

Corresponding row in Column B of sheet 2.
 
Upvote 0
Try:
Code:
Sub CompareLists()
    Application.ScreenUpdating = False
    Dim Rng As Range
    Dim foundVal As Range
    Dim LastRow As Long
    LastRow = Sheets("Sheet1").Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    For Each Rng In Sheets("Sheet1").Range("A1:A" & LastRow)
        Set foundVal = Sheets("Sheet2").Range("A:A").Find(Rng, LookIn:=xlValues, looat:=xlWhole)
        If Not foundVal Is Nothing Then
            Rng.Offset(0, 1).Copy foundVal.Offset(0, 1)
        End If
    Next Rng
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Try:
Code:
Sub CompareLists()
    Application.ScreenUpdating = False
    Dim Rng As Range
    Dim foundVal As Range
    Dim LastRow As Long
    LastRow = Sheets("Sheet1").Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    For Each Rng In Sheets("Sheet1").Range("A1:A" & LastRow)
        Set foundVal = Sheets("Sheet2").Range("A:A").Find(Rng, LookIn:=xlValues, looat:=xlWhole)
        If Not foundVal Is Nothing Then
            Rng.Offset(0, 1).Copy foundVal.Offset(0, 1)
        End If
    Next Rng
    Application.ScreenUpdating = True
End Sub

Where do I enter this code?
 
Upvote 0
Do the following: Hold down the ALT key and press the F11 key. This will open the Visual Basic Editor. In the menu at the top click 'Insert' and then click 'Module'. Copy and paste the macro into the empty code window that opens up. Press the F5 key to run the macro. Close the code module window to return to your sheet. There are other quicker ways to run the macro such as assigning it to a button that you would click on your sheet or assigning it to a short cut key.
 
Upvote 0
Run-time error '448':

Named argument not found

In selecting "Debug," the following string is highlighted:

Set foundVal = Sheets("Sheet2").Range("A:A").Find(Rng, LookIn:=xlValues, looat:=xlWhole)
 
Upvote 0
My apologies, there is a typo. Replace
Code:
 looat:=xlWhole
with
Code:
 Lookat:=xlWhole
 
Upvote 0

Forum statistics

Threads
1,213,490
Messages
6,113,956
Members
448,535
Latest member
alrossman

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