Copy/Paste named ranges to different positions in another worksheet

darxtar

New Member
Joined
Jun 25, 2011
Messages
3
Hello there,

I am trying to convert the following code into a loop. The relationship between "Cascades_xx" and "Master_xx" changes depending on the total number of named ranges, and is contained in a separate table. Currently I enter the values manually for anywhere up to 200 named ranges. Below is a short version of the code I have:

Worksheets("Cascades").Range("Cascades_1").Copy _
Destination:=Worksheets("Master").Range("Master_3")
Worksheets("Cascades").Range("Cascades_2").Copy _
Destination:=Worksheets("Master").Range("Master_2")
Worksheets("Cascades").Range("Cascades_3").Copy _
Destination:=Worksheets("Master").Range("Master_1")
Worksheets("Cascades").Range("Cascades_4").Copy _
Destination:=Worksheets("Master").Range("Master_5")
Worksheets("Cascades").Range("Cascades_5").Copy _
Destination:=Worksheets("Master").Range("Master_4")

So what I'm after is a way to look up the corresponding "Master_xx" named range for each "Cascade_xx" named range, and then copy the "Cascade_xx" named range to that position.

Much appreciated.
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Code:
    Dim Lookups As Variant, r As Long
    
    ' Lookup table is on Sheet1 columns A and B
    With Sheets("Sheet1")
        Lookups = .Range("A1", .Range("A" & Rows.Count).End(xlUp)).Resize(, 2)
    End With
    
    For r = 1 To UBound(Lookups, 1)
        Worksheets("Cascades").Range("Cascades_" & Lookups(r, 1)).Copy _
            Destination:=Worksheets("Master").Range("Master_" & Lookups(r, 2))
    Next r

Example Lookup table on Sheet1
<table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">2</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">3</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">4</td><td style="text-align: right;;">5</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">5</td><td style="text-align: right;;">4</td></tr></tbody></table><br /><br />
 
Upvote 0
Perfect! That's exactly the result I require. Many thanks, AlphaFrog for saving many minutes of manual data entry.
 
Upvote 0

Forum statistics

Threads
1,224,514
Messages
6,179,219
Members
452,895
Latest member
BILLING GUY

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