AutoFit Merged Cell Row Height

You’ve most likely heard this warning — “Avoid merged cells in your Excel worksheets!” And that is excellent advice. Merged cells can cause problems, especially when they’re in a table that you’ll be sorting and filtering.

Forced to Merge

Occasionally though, you might have no choice but to use one or more merged cells on a worksheet. As long as you avoid merging table cells, and proceed with caution, things might be okay.
In the example shown below, there is an order form, and space for a note about the order. If the note will always be short, there’s no need to merge the cells – just let the text flow across the columns.
mergecellsautofit01
However, if the notes will be two or more lines, you’ll need to merge the cells, and turn on Wrap Text. Adjusting the column width would affect the product list that starts in row 12, so that’s not an option.

Merged Cell Row Height

Usually, if you add more text to a single cell, and Wrap Text is turned on, the row height automatically adjusts, to fit the text.
When the cells are merged in row 10, the row height has to be manually adjusted when the text changes. That works well, as long as you remember to do it, but it can be a nuisance, if the text changes frequently.
And if you forget to adjust the row height, you might print the order form, while key instructions are hidden.
mergecellsautofit02

Automatically Adjust Row Height

To fix the worksheet, so the merged cells adjust automatically, you can add event code to the worksheet.
[Update: The original code is below, and there are several modified versions of the code in the comments. There is also an updated version of Smallman’s code in this December 2015 blog post.]
The merged cells are named OrderNote, and that name will be referenced in the event code.
mergecellsautofit03
We want the row height to adjust if the OrderNote range is changed, so we’ll add code to the Worksheet_Change event. The code that I use is based on an old Excel newsgroup example, that was posted by Excel MVP, Jim Rech.
Note: As Jeff Weir pointed out in the comments below, this code will wipe out the Undo stack, so you won’t be able to undo any steps you’ve previously taken. So, instead of using the Worksheet_Change event, you could use the workbook’s BeforePrint event, to reduce the Undo problem.

  1. Right-click on the sheet tab, and paste the following code on the worksheet module. Note: Only one Worksheet_Change event is allowed in each worksheet module.
  2. Change the range name from “OrderNote”, to the named range on your worksheet.
  3. If your worksheet is protected, you can add code to unprotect and protect the worksheet.
Private Sub Worksheet_Change(ByVal Target As Range)
Dim MergeWidth As Single
Dim cM As Range
Dim AutoFitRng As Range
Dim CWidth As Double
Dim NewRowHt As Double
Dim str01 As String
str01 = "OrderNote"
  If Not Intersect(Target, Range(str01)) Is Nothing Then
    Application.ScreenUpdating = False
    On Error Resume Next
    Set AutoFitRng = Range(Range(str01).MergeArea.Address)
    With AutoFitRng
      .MergeCells = False
      CWidth = .Cells(1).ColumnWidth
      MergeWidth = 0
      For Each cM In AutoFitRng
          cM.WrapText = True
          MergeWidth = cM.ColumnWidth + MergeWidth
      Next
      'small adjustment to temporary width
      MergeWidth = MergeWidth + AutoFitRng.Cells.Count * 0.66
      .Cells(1).ColumnWidth = MergeWidth
      .EntireRow.AutoFit
      NewRowHt = .RowHeight
      .Cells(1).ColumnWidth = CWidth
      .MergeCells = True
      .RowHeight = NewRowHt
    End With
    Application.ScreenUpdating = True
  End If
End Sub

How It Works

The event code checks to see if the changed cell is in the OrderNote range. If it is, the code runs, and does the following:

  1. Unmerge the cells
  2. Get the width of the first column in the OrderNote range
  3. Get the total width for all columns in the OrderNote range
  4. Add a little extra to the calculated width
  5. Set the first column to the calculated total width
  6. Autofit the row, based on the note next in the first column
  7. Get the new row height
  8. Change the first column to its original width
  9. Merge the cells
  10. Set the row height to the new height

Screen updating is turned off while the code runs, and it all happens in the blink of an eye.

Test the Event Code

To test the code, make a change to the text in the named merged cells, then press Enter. The row height should adjust automatically.
Is this something that you’ll use in your workbooks? Please let me know in the comments.
__________________