Problem copying worksheet to new workbook with VBA

mcomp72

Active Member
Joined
Aug 14, 2016
Messages
275
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2011
Platform
  1. Windows
  2. MacOS
I am attempting to write code that will create a new workbook, and then copy a sheet from ThisWorkbook (sheet is named "PO Form") into that new workbook. I have not done this before using VBA, and have hit a roadblock.

Here's the simplified version of my code:

Code:
Dim NewWBname As String
Dim POwb As Workbook

NewWBname = Application.GetSaveAsFilename( _
FileFilter:="XLSX files, *.xlsx", _
Title:="Export POs as Excel file...")

Set POwb = Workbooks.Add
POwb.SaveAs NewWBname

ThisWorkbook.Activate
    
Sheets("PO Form").Select
Sheets("PO Form").Copy After:=Workbooks(NewWBname).Sheets(1)

On the last line, I am getting Run-time error 9: subscript out of range. I searched around online, and I've seen various forums that indicate this is the proper syntax for copying a sheet to a new workbook. But obviously I am misunderstanding something. Any help would be appreciated!
 

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.
Try
Code:
Dim NewWBname As String

NewWBname = Application.GetSaveAsFilename( _
   FileFilter:="XLSX files, *.xlsx", _
   Title:="Export POs as Excel file...")
Sheets("Pcode").Copy

ActiveWorkbook.SaveAs NewWBname, 51
 
Upvote 0
My code is actually going to potentially copy the sheet several times, depending on the circumstances, so I have a FOR NEXT loop to determine how many times. And the line to copy the sheet is actually well below the line to get the new file name. In the code in between the two, I have to activate ThisWorkbook because of what the code needs to do. So I would like to use the Copy line like the way I had it, but I don't understand why it isn't working as written.
 
Upvote 0
Its because NewWBname includes the full path, rather than just the file name.
Try
Code:
Dim NewWBname As String
Dim POwb As Workbook

NewWBname = Application.GetSaveAsFilename( _
FileFilter:="XLSX files, *.xlsx", _
Title:="Export POs as Excel file...")

Set POwb = Workbooks.Add
POwb.SaveAs NewWBname

ThisWorkbook.Activate
    
Sheets("PO Form").Copy After:=POwb.Sheets(1)
 
Upvote 0
AHHH! Yep, that fixed it. Thank you!! :cool:
 
Upvote 0

Forum statistics

Threads
1,214,400
Messages
6,119,289
Members
448,885
Latest member
LokiSonic

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