Written by Allen Wyatt (last updated May 20, 2023)
This tip applies to Excel 2007, 2010, 2013, and 2016
Linda asked if there is a way to calculate only the active workbook. When a recalc is performed by Excel, it recalculates all her open workbooks, and if they are very large workbooks it can sometimes take over fifteen minutes to recalc. If she is able to limit what is recalculated, then the process will obviously run faster.
Unfortunately, there is no direct method to just calculate a particular workbook. You can, however, calculate just the active worksheet, if desired. First, set the recalculation mode to manual by following these steps:
Figure 1. The Formulas options of the Excel Options dialog box.
Now the only time your workbook (actually, all your open workbooks) will be recalculated is when you press F9. If you want to recalculate only the current worksheet, then press Shift+F9.
Excel also provides macro functions that allow you to do any of these three things: calculate all open workbooks, calculate a specific worksheet in a workbook, or calculate a specified range of cells on a worksheet. With this knowledge you could create a macro that would loop through all the worksheets in a workbook and recalculate each of them.
The following macro sets the calculation mode to manual (so the other workbooks will not calculate) and then loops through and calculates each sheet of the active workbook.
Sub CalcBook() Dim wks As Worksheet Application.Calculation = xlManual For Each wks In ActiveWorkbook.Worksheets wks.Calculate Next Set wks = Nothing End Sub
If you believe that you may want to calculate different parts of your workbook at different times, you can expand the macro so that it will perform any type of calculation you may want:
Sub CalcWhat() Dim iAnsure As Integer Application.Calculation = xlManual iAnsure = InputBox("1 = Calculate A Used Range" _ & vbCrLf & _ "2 = Calculate This Worksheet" _ & vbCrLf & _ "3 = Calculate This Workbook" _ & vbCrLf & _ "4 = Calculate All Workbooks in Memory" _ & vbCrLf & vbCrLf & _ "Input Your Selection Number From Above" _ & vbCrLf & "Then Click OK", _ "Calculate What?", "Input Number Please", _ 5000, 5000) Select Case iAnsure Case 1 'Range Only Selection.Calculate Case 2 'Worksheet Only ActiveSheet.Calculate Case 3 'Workbook Only For Each wks In ActiveWorkbook.Worksheets wks.Calculate Next Case 4 'All Open Workbooks Application.CalculateFull End End Select End Sub
This macro presents an input box that prompts the user as to which type of recalculation is desired. When the user enters a number from 1 to 4, the desired type of recalculation is performed.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6752) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Calculating Only the Active Workbook.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
One of the most basic of programming structures is the conditional structure: If ... End If. This tip explains how this ...
Discover MoreAt times, you may want your macro to pause execution. This tip presents four different ways you can add a delay into your ...
Discover MoreIt is not uncommon to set variables in a macro based on other values, such as time or date. You could also set variables ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments