VBA Copy and paste from one workbook to another

TaskMaster

Board Regular
Joined
Oct 15, 2020
Messages
55
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi All,

I am trying to copy and paste values from two separate documents into my main document "Re-build v6". I have got the file locations in cells S2 & S3 and the file name in T2 & T3, as this is a daily file the file name changes and I want to copy the most up to date info. I keep getting an error at "Windows(FileName1).Activate"

S2 = 11. November\Daily Movements - 24.11.20
S3 = 11. November\Daily Movements - 25.11.20
T2 = Daily Movements - 24.11.20.xlsm
T3 = Daily Movements - 25.11.20.xlsm

Thanks in advance.

VBA Code:
Sub Macro1()
'
' Copy Values

Dim FileLocation As String
Dim FileLocation1 As String
Dim FileLocation2 As String
Dim FilePath1 As String
Dim FilePath2 As String
Dim FileName1 As String
Dim FileName2 As String

FileLocation = "\\Users\Documents\Test"
FileLocation1 = "S2"
FileLocation2 = "S3"
FileName1 = "T2"
FileName2 = "T3"
FilePath1 = FileLocation & "\" & Range(FileLocation1).Value & ".xlsm"
FilePath2 = FileLocation & "\" & Range(FileLocation2).Value & ".xlsm"

    Workbooks.Open (FilePath1)
    Windows(FileName1).Activate
    Sheets("Movements").Select
    Range("C6").Select
    Selection.Copy
    Windows("Re-build v6.xlsm").Activate
    Range("D24").Select
    Selection.PasteSpecial Paste:=xlPasteValues
    Windows(FileName1).Activate
    Range("C5").Select
    Selection.Copy
    Windows("Re-build v6.xlsm").Activate
    Range("D26").Select
    Selection.PasteSpecial Paste:=xlPasteValues
    Windows(FileName1).Activate
    ActiveWindow.Close SaveChanges:=False
    Workbooks.Open (FilePath2)
    Sheets("Movements").Select
    Range("M6").Select
    Selection.Copy
    Windows("Re-build v6.xlsm").Activate
    Range("D25").Select
    Selection.PasteSpecial Paste:=xlPasteValues
    Windows(FileName2).Activate
    Range("M5").Select
    Selection.Copy
    Windows("Re-build v6.xlsm").Activate
    Range("D27").Select
    Selection.PasteSpecial Paste:=xlPasteValues
    Windows(FileName2).Activate
    ActiveWindow.Close SaveChanges:=False
End Sub
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
How about
VBA Code:
Sub Macro1()
'
' Copy Values

Dim FileLocation As String
Dim FileLocation1 As String
Dim FileLocation2 As String
Dim FilePath1 As String
Dim FilePath2 As String
Dim FileName1 As String
Dim FileName2 As String
Dim Wbk As Workbook

FileLocation = "\\Users\Documents\Test"
FileLocation1 = "S2"
FileLocation2 = "S3"
FileName1 = "T2"
FileName2 = "T3"
FilePath1 = FileLocation & "\" & Range(FileLocation1).Value & ".xlsm"
FilePath2 = FileLocation & "\" & Range(FileLocation2).Value & ".xlsm"

   With Workbooks("Re-build v6.xlsm").ActiveSheet
      Set Wbk = Workbooks.Open(FilePath1)
      .Range("D24").Value = Wbk.Sheets("Movements").Range("C6").Value
      .Range("D26").Value = Wbk.Sheets("Movements").Range("C5").Value
      Wbk.Close False
      Set Wbk = Workbooks.Open(FilePath2)
      .Range("D25").Value = Wbk.Sheets("Movements").Range("M6").Value
      .Range("D27").Value = Wbk.Sheets("Movements").Range("M5").Value
      Wbk.Close False
   End With
End Sub
 
Upvote 0
Solution
Try this approach. You will be prompted to select the 2 files with a reminder to select them in order, first File1 and then File2. This means that you won't need the file paths and file names in S2:T3 which saves you from having to update them daily.
VBA Code:
Sub CopyRanges()
    Application.ScreenUpdating = False
    Dim desWS As Worksheet, WB1 As Workbook, WB2 As Workbook, srcWS1 As Worksheet, srcWS2 As Worksheet, vSelectedItem As Variant
    Set desWS = ThisWorkbook.ActiveSheet
    Dim flder As FileDialog
    Set flder = Application.FileDialog(msoFileDialogFilePicker)
    With flder
        MsgBox ("Please select File1 first and then File2.")
        .Title = "Please select the two files in order."
        .AllowMultiSelect = True
        If .Show = -1 Then
            Set WB1 = Workbooks.Open(.SelectedItems(1))
            With Sheets("Movements")
                desWS.Range("D24").Value = .Range("C6").Value
                desWS.Range("D26").Value = .Range("C5").Value
            End With
            Set WB2 = Workbooks.Open(.SelectedItems(2))
            With Sheets("Movements")
                desWS.Range("D25").Value = .Range("M6").Value
                desWS.Range("D27").Value = .Range("M5").Value
            End With
            WB1.Close False
            WB2.Close False
        End If
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
How about
VBA Code:
Sub Macro1()
'
' Copy Values

Dim FileLocation As String
Dim FileLocation1 As String
Dim FileLocation2 As String
Dim FilePath1 As String
Dim FilePath2 As String
Dim FileName1 As String
Dim FileName2 As String
Dim Wbk As Workbook

FileLocation = "\\Users\Documents\Test"
FileLocation1 = "S2"
FileLocation2 = "S3"
FileName1 = "T2"
FileName2 = "T3"
FilePath1 = FileLocation & "\" & Range(FileLocation1).Value & ".xlsm"
FilePath2 = FileLocation & "\" & Range(FileLocation2).Value & ".xlsm"

   With Workbooks("Re-build v6.xlsm").ActiveSheet
      Set Wbk = Workbooks.Open(FilePath1)
      .Range("D24").Value = Wbk.Sheets("Movements").Range("C6").Value
      .Range("D26").Value = Wbk.Sheets("Movements").Range("C5").Value
      Wbk.Close False
      Set Wbk = Workbooks.Open(FilePath2)
      .Range("D25").Value = Wbk.Sheets("Movements").Range("M6").Value
      .Range("D27").Value = Wbk.Sheets("Movements").Range("M5").Value
      Wbk.Close False
   End With
End Sub
This works perfectly, thank you.
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0
Try this approach. You will be prompted to select the 2 files with a reminder to select them in order, first File1 and then File2. This means that you won't need the file paths and file names in S2:T3 which saves you from having to update them daily.
VBA Code:
Sub CopyRanges()
    Application.ScreenUpdating = False
    Dim desWS As Worksheet, WB1 As Workbook, WB2 As Workbook, srcWS1 As Worksheet, srcWS2 As Worksheet, vSelectedItem As Variant
    Set desWS = ThisWorkbook.ActiveSheet
    Dim flder As FileDialog
    Set flder = Application.FileDialog(msoFileDialogFilePicker)
    With flder
        MsgBox ("Please select File1 first and then File2.")
        .Title = "Please select the two files in order."
        .AllowMultiSelect = True
        If .Show = -1 Then
            Set WB1 = Workbooks.Open(.SelectedItems(1))
            With Sheets("Movements")
                desWS.Range("D24").Value = .Range("C6").Value
                desWS.Range("D26").Value = .Range("C5").Value
            End With
            Set WB2 = Workbooks.Open(.SelectedItems(2))
            With Sheets("Movements")
                desWS.Range("D25").Value = .Range("M6").Value
                desWS.Range("D27").Value = .Range("M5").Value
            End With
            WB1.Close False
            WB2.Close False
        End If
    End With
    Application.ScreenUpdating = True
End Sub

How about
VBA Code:
Sub Macro1()
'
' Copy Values

Dim FileLocation As String
Dim FileLocation1 As String
Dim FileLocation2 As String
Dim FilePath1 As String
Dim FilePath2 As String
Dim FileName1 As String
Dim FileName2 As String
Dim Wbk As Workbook

FileLocation = "\\Users\Documents\Test"
FileLocation1 = "S2"
FileLocation2 = "S3"
FileName1 = "T2"
FileName2 = "T3"
FilePath1 = FileLocation & "\" & Range(FileLocation1).Value & ".xlsm"
FilePath2 = FileLocation & "\" & Range(FileLocation2).Value & ".xlsm"

   With Workbooks("Re-build v6.xlsm").ActiveSheet
      Set Wbk = Workbooks.Open(FilePath1)
      .Range("D24").Value = Wbk.Sheets("Movements").Range("C6").Value
      .Range("D26").Value = Wbk.Sheets("Movements").Range("C5").Value
      Wbk.Close False
      Set Wbk = Workbooks.Open(FilePath2)
      .Range("D25").Value = Wbk.Sheets("Movements").Range("M6").Value
      .Range("D27").Value = Wbk.Sheets("Movements").Range("M5").Value
      Wbk.Close False
   End With
End Sub
Good Evening Sir,
I just need the reverse.
Under one workbook, copy data from some specific cells of a worksheet and paste those data to several other worksheets in same cells.
Your valuable advice will be highly appreciated.
Thanks in advance.
 
Upvote 0
As this is a totally different question to the op, you need to start a new thread. Thanks
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,693
Members
448,979
Latest member
DET4492

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