VBA copy from multiple tabs of one workbook to multiple tabs of another

milab

New Member
Joined
Jun 25, 2021
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hello I'm looking to get some help with the code I have. I have the below code that opens multiples files from list, selects 2 tabs and copies values into 2 tabs into another workbook.
For reference and clarity:
FP Plan Data & OT Plan Data are worksheets to copy from
FP Plan Export & OT Plan Export are worksheets of another workbook to copy into
Sheet1 contains the list of filepaths to open

Everyone in this community has been extremely helpful and insightful so any tips or pointers would be greatly appreciated!
VBA Code:
Public Sub Copy_values()

'declare varibales
    Dim fileCells As Range, fileCell As Range
    Dim destCells As Range, r As Long
    Dim fromWorkbook As Workbook
    
    With ThisWorkbook
 
'location of filenames to open
        With .Worksheets("Sheet1")
'sets the number of times/files to do the prodecure based on the last low of data
            Set fileCells = .Range(.Range("A1"), .Cells(.Rows.Count, "A").End(xlUp))
        End With
'paste values from files into worksheet
  Set destCells = .Worksheets(Array("FP Plan Extract", "OT Plan Extract")).Range("B8:EZ20")
 
      
    End With
'disable screen updating
     Application.ScreenUpdating = False
    r = 0
'for each file that is listed do the procedure
    For Each fileCell In fileCells
'open workbooks as read only, don't update links
        Set fromWorkbook = Workbooks.Open(fileCell.Value, ReadOnly:=True, UpdateLinks:=0)
'copy values from open file
            
        destCells.Offset(r).Value = fromWorkbook.Worksheets(Array("FP Plan Data", "OT Plan Data")).Range("A7:EY19").Value

'close open file without saving
        fromWorkbook.Close SaveChanges:=False
'next file's 13 row of data
        r = r + 13
        DoEvents
    Next
      
'enable screen updating
    Application.ScreenUpdating = True
'prompt when finished
    MsgBox "Finished"
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
What you're trying to do isn't possible in one go, still it's possible.
Replace respectively these lines within your code
Code:
  Set destCells = .Worksheets(Array("FP Plan Extract", "OT Plan Extract")).Range("B8:EZ20")
  '
  ' ....
  '
  destCells.Offset(r).Value = fromWorkbook.Worksheets(Array("FP Plan Data", "OT Plan Data")).Range("A7:EY19").Value


with these lines and it might work.
VBA Code:
    Dim destFP As Range, destOT As Range
    Set destFP = .Worksheets("FP Plan Extract").Range("B8:EZ20")
    Set destOT = .Worksheets("OT Plan Extract").Range("B8:EZ20")
    '
    ' ....
    '
    destFP.Offset(r).Value = fromWorkbook.Worksheets("FP Plan Data").Range("A7:EY19").Value
    destOT.Offset(r).Value = fromWorkbook.Worksheets("OT Plan Data").Range("A7:EY19").Value
 
Upvote 0
What you're trying to do isn't possible in one go, still it's possible.
Replace respectively these lines within your code
Code:
  Set destCells = .Worksheets(Array("FP Plan Extract", "OT Plan Extract")).Range("B8:EZ20")
  '
  ' ....
  '
  destCells.Offset(r).Value = fromWorkbook.Worksheets(Array("FP Plan Data", "OT Plan Data")).Range("A7:EY19").Value


with these lines and it might work.
VBA Code:
    Dim destFP As Range, destOT As Range
    Set destFP = .Worksheets("FP Plan Extract").Range("B8:EZ20")
    Set destOT = .Worksheets("OT Plan Extract").Range("B8:EZ20")
    '
    ' ....
    '
    destFP.Offset(r).Value = fromWorkbook.Worksheets("FP Plan Data").Range("A7:EY19").Value
    destOT.Offset(r).Value = fromWorkbook.Worksheets("OT Plan Data").Range("A7:EY19").Value
@GWteB works great ! Thank you soo much, just saved me hours of work !!!!

 
Upvote 0

Forum statistics

Threads
1,214,935
Messages
6,122,337
Members
449,077
Latest member
Jocksteriom

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