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: Formatting Subtotal Rows.

Formatting Subtotal Rows

Written by Allen Wyatt (last updated March 9, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


1

When you add subtotals to a worksheet, Excel automatically formats the subtotals using a bold font. You, however, may want to have some different type of formatting for the subtotals, such as shading them in yellow or a different color.

If you use subtotals sparingly, and only want to apply a different format for one or two worksheets, you can follow these general steps:

  1. Apply your subtotals, as desired.
  2. Select the entire data table, including the subtotals.
  3. Using the Outline area at the left of the screen, collapse the detail in your worksheet so that only the subtotals are showing.
  4. Press F5 to display the Go To dialog box. (See Figure 1.)
  5. Figure 1. The Go To dialog box.

  6. Click Special to display the Go To Special dialog box. (See Figure 2.)
  7. Figure 2. The Go To Special dialog box.

  8. Select the Visible Cells Only option button.
  9. Click OK. Now, only the visible subtotal rows are selected.
  10. Apply your formatting, as desired.

If you will be repeatedly adding and removing subtotals to the same data table, you may be interested in using conditional formatting to apply the desired subtotal formatting. Follow these steps:

  1. Before applying your subtotals, select your entire data table.
  2. Make sure the Home tab of the ribbon is displayed.
  3. Click the Conditional Formatting tool. Excel displays a series of choices.
  4. Click Manage Rules. Excel displays the Conditional Formatting Rules Manager dialog box.
  5. Click New Rule. Excel displays the New Formatting Rule dialog box. (See Figure 3.)
  6. Figure 3. The New Formatting Rule dialog box.

  7. In the Select a Rule Type area at the top of the dialog box, choose Use a Formula to Determine Which Cells to Format. Excel changes the appearance of the New Formatting Rule dialog box.
  8. In the formula space, enter the following formula: =ISNUMBER(FIND("Grand Total",$A1))
  9. Click Format to display the Format Cells dialog box.
  10. Using the controls in the dialog box, set the formatting as you want it applied to the Grand Total row.
  11. Click OK to dismiss the Format Cells dialog box.
  12. Click OK to dismiss the New Formatting Rule dialog box. The rule you just created now appears in the Conditional Formatting Rules Manager dialog box.
  13. Click New Rule. Excel again displays the New Formatting Rule dialog box.
  14. In the Select a Rule Type area at the top of the dialog box, choose Use a Formula to Determine Which Cells to Format.
  15. In the formula box, enter the following formula: =ISNUMBER(FIND("Total",$A1))
  16. Click Format to display the Format Cells dialog box. (See Figure 4.)
  17. Figure 4. The Format Cells dialog box.

  18. Using the controls in the dialog box, set the formatting as you want it applied to the Total row.
  19. Click OK to dismiss the Format Cells dialog box.
  20. Click OK to dismiss the New Formatting Rule dialog box.
  21. Click the up and down arrows to move the rules you created to the order in which they should be evaluated.
  22. Click OK to dismiss the Conditional Formatting Rules Manager dialog box.

When following the above steps, make sure that you replace A1 (steps 7 and 14) with the column in which your subtotals are added. Thus, if your subtotals are in column G, you would use G1 instead of A1.

If you need to format subtotals on quite a few worksheets, then you may want to create a macro that will do the formatting for you. The following macro examines all the cells in a selected range, and then applies cell coloring, as appropriate.

Sub FormatTotalRows()
    Dim rCell as Range

    For Each rCell In Selection
        If Right(rCell.Value, 5) = "Total" Then
            Rows(rCell.Row).Interior.ColorIndex = 36
        End If

        If Right(rCell.Value, 11) = "Grand Total" Then
            Rows(rCell.Row).Interior.ColorIndex = 44
        End If
    Next
End Sub

The macro colors the subtotal rows yellow and the grand total row a darker shade of yellow. (The exact colors on your system may vary depending on the theme you have loaded.) The macro, although simple in nature, is not as efficient as it could be since every cell in the selected range is inspected. Nevertheless, on a 10 column 5000 row worksheet this macro runs in under 5 seconds.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8110) 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: Formatting Subtotal Rows.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Automatic Numbers with Leading Zeroes

Word's automatic numbering formats allow you to easily create lists that have one leading zero. If you want more than one ...

Discover More

Finding Wayward Links

Combining workbooks that have cross-links to each other can offer some special challenges. This tip examines how you can ...

Discover More

Determining a Name for a Week Number

You could use Excel to collect data that is useful in your business. For instance, you might use it to collect ...

Discover More

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!

More ExcelTips (ribbon)

Setting Row Height

When you enter information into a row on a worksheet, Excel automatically adjusts the height of the row based on what you ...

Discover More

Changing Width and Height to Inches

Want to set the width and height of a row and column by specifying a number of inches? It's not quite as straightforward ...

Discover More

Adjusting Row Height for a Number of Worksheets

Adjusting the height of a row or range of rows is relatively easy in Excel. How do you adjust the height of those same ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two less than 3?

2019-03-09 17:39:29

Ron

If you are taking the Conditional Formatting approach, instead of using FIND, you might want to use SEARCH instead. That way it won't be case-sensitive. With =ISNUMBER(FIND("Grand Total",$A1)), it will only format cells containing "Grand Total" spelled with initial capitals. However, if you use =ISNUMBER(SEARCH("Grand Total",$A1)), it will format any cell with "Grand Total" or "GRAND TOTAL" or "GRAND Total", ... or even "GrAnD ToTaL". You should also note that both FIND and SEARCH equate to "contains". So you can FIND/SEARCH for just "Total" an it will format any cells with "Subtotal" or "Grand Total" or "Total for ...", etc.


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.