VBA - Get data from other WB, chossing sheet from dropdown

Mikael_L

New Member
Joined
Mar 29, 2021
Messages
14
Office Version
  1. 365
Platform
  1. Windows
Hi forum :)

I'm trying to make my workbook (Schedule) to get data from another workbook (BOQ) depending on what sheet that is chosen in my dropdown in "E3".
The dropdown in generated from a VBA which get the "BOQ's" sheetnames.

I would then like to when I change the dropdown value, the sheet gets the data from the BOQ's matching sheetname in range B8:P90, and paste it into the "Schedule" workbook's active sheet.


Hope the above makes sense
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Assuming that the target workbook (BOQ.xlsx) is currently open, so you would like that when a worksheet is selected in E3 of the starting worksheet then range B8:P90 of the target worksheet on the target workbook be copied and pasted onto the starting worksheet in position xxxx (missing information).
You could do that with the following macro:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Address = "$E$3" Then
    If Target.Value <> "" Then
        Workbooks("BOQ.xlsx").Sheets(Range("E3").Value).Range("B8:P90").Copy _
            ActiveSheet.Range("A5")              '<<< POSITION IS JUST AN EXAMPLE
    End If
End If
End Sub
This is a "Worksheet_Change" macro, so the code has to be pasted into the "sheet's vba module" of the starting worksheet (the one with the dropdown in E3): right click on the tab with the name of the sheet, chose "Display code"; this will open the vba programming environment at the right position. Copy the above code and paste it into the right empty frame (if it already contains other macros then we have to check for incompatibility)
Adapt the line marked <<<, for the correct position where the copied area has to be pasted; check also for the extension of workbook BOQ (I used xlsx)

Now change the selection in E3 and check that what happens is what you wish.

Bye
 
Upvote 0
Assuming that the target workbook (BOQ.xlsx) is currently open, so you would like that when a worksheet is selected in E3 of the starting worksheet then range B8:P90 of the target worksheet on the target workbook be copied and pasted onto the starting worksheet in position xxxx (missing information).
You could do that with the following macro:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Address = "$E$3" Then
    If Target.Value <> "" Then
        Workbooks("BOQ.xlsx").Sheets(Range("E3").Value).Range("B8:P90").Copy _
            ActiveSheet.Range("A5")              '<<< POSITION IS JUST AN EXAMPLE
    End If
End If
End Sub
This is a "Worksheet_Change" macro, so the code has to be pasted into the "sheet's vba module" of the starting worksheet (the one with the dropdown in E3): right click on the tab with the name of the sheet, chose "Display code"; this will open the vba programming environment at the right position. Copy the above code and paste it into the right empty frame (if it already contains other macros then we have to check for incompatibility)
Adapt the line marked <<<, for the correct position where the copied area has to be pasted; check also for the extension of workbook BOQ (I used xlsx)

Now change the selection in E3 and check that what happens is what you wish.

Bye

Hi Anthony47,
This worked great, Thanks !!
 
Upvote 0

Forum statistics

Threads
1,214,889
Messages
6,122,097
Members
449,065
Latest member
albertocarrillom

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