Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Formatting Subtotal Rows

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Formatting Subtotal Rows.

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. Choose Conditional Formatting from the Formatting menu. Excel displays the Conditional Formatting dialog box.
  3. In the left-most drop-down list, choose Formula Is. The dialog box changes to reflect your choice. (See Figure 3.)
  4. Figure 3. The Conditional Formatting dialog box.

  5. In the formula box, just to the right of the drop-down list used in step 3, enter the following formula: =ISNUMBER(FIND("Grand Total",$A1))
  6. Click Format to display the Format Cells dialog box.
  7. Using the controls in the dialog box, set the formatting as you want it applied to the Grand Total row.
  8. Click OK to dismiss the Format Cells dialog box.
  9. Click Add. Excel adds a second conditional format.
  10. In the left-most drop-down list of the second condition, choose Formula Is. The dialog box changes to reflect your choice.
  11. In the formula box, just to the right of the drop-down list used in step 9, enter the following formula: =ISNUMBER(FIND("Total",$A1))
  12. Click Format to display the Format Cells dialog box. (See Figure 4.)
  13. Figure 4. The Format Cells dialog box.

  14. Using the controls in the dialog box, set the formatting as you want it applied to the Total row.
  15. Click OK to dismiss the Format Cells dialog box.
  16. Click OK to dismiss the Conditional Formatting dialog box.

When following the above steps, make sure that you replace A1 (steps 4 and 10) 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 do formatting of 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 orange. 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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2984) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Formatting Subtotal Rows.

Related Tips:

Organize Your Data! Using the powerful sorting capabilities of Excel can help you get your data into just the order you need. Find out how you can use the full capabilities of sorting to your benefit. Check out ExcelTips: Serious Sorting today!

 

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form below!)

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 3+4? (To prevent automated submissions and spam.)
 
          Commenting Terms
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2013)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2013)

Our Products

Premium Newsletters

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2014 Sharon Parq Associates, Inc.