You might try walking through the copy, new workbook, paste, saveas, close
once with the macro recorder on. Then you can go back into it, add the
objects and the filename string, and put the loop in.
Ed
"Min" <M...@discussions.microsoft.com> wrote in message
news:A3410FA2-C50D-4B8E...@microsoft.com...
Private Const strPATH As String = "C:\"
Private Sub SaveSheets()
Dim wks As Worksheet
For Each wks In Worksheets
wks.Copy
ActiveWorkbook.SaveAs strPATH & wks.Name
ActiveWorkbook.Close
Next wks
End Sub
Ed
"Jim Thomlinson" <JimTho...@discussions.microsoft.com> wrote in message
news:992732DD-7487-401E...@microsoft.com...
This is now the active workbook. You can refernce the original workbook as
thisworkbook (but we don't need to in this case).
Save and close the active workbook and go on to the next sheet.
With a little practice comes ability. With a lot of practice comes simplicity.
That's a mouthful, Jim. I will remember that. Thanks.
Ed
"Jim Thomlinson" <JimTho...@discussions.microsoft.com> wrote in message
news:C302EC21-85A0-47DB...@microsoft.com...
> wks.copy creates a new workbook with just that sheet in it. Same as right
> click on that tab -> Create Copy -> In new Workbook.
>
> This is now the active workbook. You can refernce the original workbook as
> thisworkbook (but we don't need to in this case).
>
> Save and close the active workbook and go on to the next sheet.
>