Before Close Multiple Inactive Workbook Close

Bench

Board Regular
Joined
Aug 27, 2009
Messages
134
Hi I wrote a simple function to open 3 workbooks upon opening a workbook,

Then i wrote a simple one to close the 3 workbooks, this works fine as a sub,

However when placed as a Private Sub in the BeforeClose section it doesn't work and tells me subscript is out of range

any ideas?

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
    Windows("Expenditures.xlsx").Activate
    ActiveWindow.Close
    Windows("Coast Prices.xlsx").Activate
    ActiveWindow.Close
    Windows("Field Service Report.xls").Activate
    ActiveWindow.Close
    Range("A1").Select
End Sub
 

Some videos you may like

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK

HalfAce

MrExcel MVP
Joined
Apr 6, 2003
Messages
9,453
Hello Bench,
One thing I see is that 'Expenditures' and 'Coast Prices' both have the xlsx file extension while
'Field Service Report' uses the xls extension. Is this correct or a typo?
(I'll assume it is correct for now as you stated that your routine runs fine as a standard sub.)
If that's correct then you might try this in your ThisWorkbook module of the controlling workbook instead.
Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
  Workbooks("Expenditures.xlsx").Close False
  Workbooks("Coast Prices.xlsx").Close False
  Workbooks("Field Service Report.xls").Close False
  Range("A1").Select
End Sub
This should close those 3 files from the fourth, without saving them or asking if you want it to.
If you DO want them to save before closing, then simply replace the 3 instances of Close False with Close True
(If you want to be asked if you want any changes saved, then just use 'Close' without any False or True.)
Also note, that we seldom need to activate (or select) an object to work with it. Here we're just referring to them instead of activating them.

Hope it helps.
 

Bench

Board Regular
Joined
Aug 27, 2009
Messages
134
Hello Bench,
One thing I see is that 'Expenditures' and 'Coast Prices' both have the xlsx file extension while
'Field Service Report' uses the xls extension. Is this correct or a typo?
(I'll assume it is correct for now as you stated that your routine runs fine as a standard sub.)
If that's correct then you might try this in your ThisWorkbook module of the controlling workbook instead.
Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
  Workbooks("Expenditures.xlsx").Close False
  Workbooks("Coast Prices.xlsx").Close False
  Workbooks("Field Service Report.xls").Close False
  Range("A1").Select
End Sub
This should close those 3 files from the fourth, without saving them or asking if you want it to.
If you DO want them to save before closing, then simply replace the 3 instances of Close False with Close True
(If you want to be asked if you want any changes saved, then just use 'Close' without any False or True.)
Also note, that we seldom need to activate (or select) an object to work with it. Here we're just referring to them instead of activating them.

Hope it helps.
Hey thanks for this, i managed to get around it by calling a useform but this is much more straightforward. And yes the .xls and .xlsx's come from the joys of working with diff versions of excel at home and work

Thanks for your help
 

HalfAce

MrExcel MVP
Joined
Apr 6, 2003
Messages
9,453
Most welcome. Glad it helped.

EDIT:
If there's any chance a user might close one of your 3 named files before closing the one this routine resides in you might want to think about inserting as your first line of code:
On Error Resume Next
and then
On Error GoTo 0
at the very end.

S'pose I should've thought of that earlier...
 
Last edited:

Watch MrExcel Video

Forum statistics

Threads
1,099,335
Messages
5,468,003
Members
406,563
Latest member
kdorClintR

This Week's Hot Topics

Top