Macro copy data to not open workbook

ste33uka

Active Member
Joined
Jan 31, 2020
Messages
358
Office Version
  1. 2019
Platform
  1. Windows
I use the following macro to copy data from an open workbook to a workbook called "stored", sheet "data" if D1 value is "yes"
Is it possible to copy data without workbook "stored" being open ?


VBA Code:
Sub copy_to_dataworkbook()
   Dim i As Long
   For i = 1 To 60
      With Sheets(CStr(i))
         If LCase(.Range("D1").Value) = "yes" Then
          .Range("Vs86:WH105").Copy
            Workbooks("stored").Sheets("data").Range("cu" & Rows.Count).End(xlUp).Offset(2).PasteSpecial xlPasteValues
         End If
      End With
   Next i
End Sub
 

Some videos you may like

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.

NdNoviceHlp

Well-known Member
Joined
Nov 9, 2002
Messages
2,766
No but U can open the wb, put stuff in it and close it in the background without even knowing that it was open... sort of the same. HTH. Dave
 

ste33uka

Active Member
Joined
Jan 31, 2020
Messages
358
Office Version
  1. 2019
Platform
  1. Windows
No but U can open the wb, put stuff in it and close it in the background without even knowing that it was open... sort of the same. HTH. Dave
Would you have a macro code for that ?
 

NdNoviceHlp

Well-known Member
Joined
Nov 9, 2002
Messages
2,766
Untested code. Please make a back up of your file before you test the code. Dave
Code:
Sub copy_to_dataworkbook()
Dim i As Long, FSO As Object, FilDir As Object
On Error GoTo QuitThis
Application.ScreenUpdating = False
Application.Calculation = xlCalculationManual
Application.DisplayAlerts = False
Set FSO = CreateObject("scripting.filesystemobject")
'***change File path to your file
Set FilDir = FSO.getfile("C:\Users\home\Desktop\stored.xlsm")
Workbooks.Open Filename:=FilDir
   For i = 1 To 60
      With ThisWorkbook.Sheets(CStr(i))
         If LCase(.Range("D1").Value) = "yes" Then
          .Range("Vs86:WH105").Copy
            Workbooks(FilDir.Name).Sheets("data").Range("cu" & Rows.Count) _
                    .End(xlUp).Offset(2).PasteSpecial xlPasteValues
         Application.CutCopyMode = False
         End If
      End With
   Next i
Workbooks(FilDir.Name).Close SaveChanges:=True
QuitThis:
Set FSO = Nothing
Set FilDir = Nothing
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
Application.DisplayAlerts = True
End Sub
edit: changed save to true
 
Last edited:
Solution

mohadin

Well-known Member
Joined
Mar 22, 2015
Messages
1,091
Office Version
  1. 2013
Platform
  1. Windows

ADVERTISEMENT

Hi
What about
VBA Code:
Sub copy_to_dataworkbook()
   Dim i As Long
   Dim wb
   Set wb = Workbooks.Open("C:\Users\home\Desktop\stored.xlsx")
   For i = 1 To 60
      With Sheets(CStr(i))
         If LCase(.Range("D1").Value) = "yes" Then
          .Range("Vs86:WH105").Copy
            wb.Sheets("data").Range("cu" & Rows.Count).End(xlUp).Offset(2).PasteSpecial xlPasteValues
         End If
      End With
   Next i
   wb.Close False
End Sub
 

NdNoviceHlp

Well-known Member
Joined
Nov 9, 2002
Messages
2,766
Missed the edit timer. Added some error msg along with the save change.
Code:
Sub copy_to_dataworkbook()
Dim i As Long, FSO As Object, FilDir As Object
On Error GoTo QuitThis
Application.ScreenUpdating = False
Application.Calculation = xlCalculationManual
Application.DisplayAlerts = False
Set FSO = CreateObject("scripting.filesystemobject")
'***change File path to your file
Set FilDir = FSO.getfile("C:\Users\home\Desktop\stored.xlsm")
Workbooks.Open Filename:=FilDir
   For i = 1 To 60
      With ThisWorkbook.Sheets(CStr(i))
         If LCase(.Range("D1").Value) = "yes" Then
          .Range("Vs86:WH105").Copy
            Workbooks(FilDir.Name).Sheets("data").Range("cu" & Rows.Count) _
                    .End(xlUp).Offset(2).PasteSpecial xlPasteValues
         Application.CutCopyMode = True
         End If
      End With
   Next i
Workbooks(FilDir.Name).Close SaveChanges:=True
QuitThis:
If Err.Number <> 0 Then
On Error GoTo 0
MsgBox "Error"
End If
Set FSO = Nothing
Set FilDir = Nothing
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
Application.DisplayAlerts = True
End Sub
Dave
 

ste33uka

Active Member
Joined
Jan 31, 2020
Messages
358
Office Version
  1. 2019
Platform
  1. Windows
Untested code. Please make a back up of your file before you test the code. Dave
Code:
Sub copy_to_dataworkbook()
Dim i As Long, FSO As Object, FilDir As Object
On Error GoTo QuitThis
Application.ScreenUpdating = False
Application.Calculation = xlCalculationManual
Application.DisplayAlerts = False
Set FSO = CreateObject("scripting.filesystemobject")
'***change File path to your file
Set FilDir = FSO.getfile("C:\Users\home\Desktop\stored.xlsm")
Workbooks.Open Filename:=FilDir
   For i = 1 To 60
      With ThisWorkbook.Sheets(CStr(i))
         If LCase(.Range("D1").Value) = "yes" Then
          .Range("Vs86:WH105").Copy
            Workbooks(FilDir.Name).Sheets("data").Range("cu" & Rows.Count) _
                    .End(xlUp).Offset(2).PasteSpecial xlPasteValues
         Application.CutCopyMode = False
         End If
      End With
   Next i
Workbooks(FilDir.Name).Close SaveChanges:=True
QuitThis:
Set FSO = Nothing
Set FilDir = Nothing
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
Application.DisplayAlerts = True
End Sub
edit: changed save to true
Thanks alot for your help on that, that worked , job done
 

Watch MrExcel Video

Forum statistics

Threads
1,127,328
Messages
5,624,036
Members
416,007
Latest member
csf

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
Top