Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Moving Subtotals.
Written by Allen Wyatt (last updated June 13, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
David was adding subtotals (Data tab of the ribbon, in the Outline group) to large worksheets and looking for a way to move the subtotal cells to different cells. For instance, assume that when Excel added the automatic subtotals, they were added in column S, and the SUBTOTAL formula added by Excel referred to ranges of cells in column S. David wanted to move the SUBTOTAL formulas (and only those formulas) out of column S to column T, and have the formulas still refer to detail in column S.
One option is to go through and move the SUBTOTAL formulas, one at a time, to the desired locations. (You would use Ctrl+X and Ctrl+V to move the cells, rather than Ctrl+C and Ctrl+V to merely create copies of the cells.) If the worksheets are large, with many subtotals, this can become very tedious very quickly.
Tedium in Excel is often the primary impetus for creating a macro. This case is no exception. It is possible to create a macro that will do the actual move of the SUBTOTAL formulas. Consider the following example:
Sub MoveSubtotals() Dim rCell As Range Dim rng As Range Dim iCol As Integer Dim iOffset As Integer iCol = 19 '19 is Column S iOffset = 1 'Positives go right, negatives go left Set rng = Intersect(Selection.CurrentRegion, Columns(iCol)) For Each rCell In rng If InStr(rCell.Formula, "SUBTOTAL") Then rCell.Offset(0, iOffset).Formula = _ rCell.Formula rCell.ClearContents End If Next End Sub
This example works by examining each cell selected in column S. If the formula in the cell contains the word SUBTOTAL, then the formula is copied one column to the right, in column T, and deleted from the cell in column S. You can change the distance left or right that the subtotals are moved by simply changing the value assigned to the iOffset variable.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8643) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Moving Subtotals.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
You can insert subtotals and totals in your worksheets by using either a formula or specialized tools. This tip explains ...
Discover MoreThe Trace Precedents auditing tool can be quite helpful in seeing which cells "feed into" a particular formula. The ...
Discover MoreExcel provides some great tools that can help you see the relationships between the formulas in your worksheets. These ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-06-18 12:51:32
J. Woolley
@Rick Leisner
Your suggestion is excellent.
The Tip's macro depends upon the range that was selected before it was initiated. And it might miss the final Grand Total. It would be more reliable if the following statement
Set rng = Intersect(Selection.CurrentRegion, Columns(iCol))
was replaced by this statement
Set rng = Intersect(ActiveSheet.UsedRange, Columns(iCol))
Also, Columns(iCol) can be replaced by Columns("S"), which is perhaps easier to understand.
2024-06-13 16:36:27
Rick Leisner
Does inserting a cell and shifting right work? And then hit F4 everywhere else you want to do it. That would be easier than ^X and ^V. Or am I misunderstanding?
2020-08-03 09:56:16
RKeev
Try selecting your subtotals formulas, replace the equals sign with ppp using the find and replace, then copy that area and paste to the desired area. Then run the find and replace again replacing the ppp with the equals sign.
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 © 2024 Sharon Parq Associates, Inc.
Comments