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
 

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:

Forum statistics

Threads
1,082,106
Messages
5,363,180
Members
400,720
Latest member
Pettel

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top