Why Can't My Row Height Automatically Adjust?!

What Is AutoFit Column Width & AutoFit Row Height?

This is a feature that I tend to use a lot when formatting my spreadsheets.  Essentially what you can do is double-click between two rows or two columns in the row or column heading area (as shown below) and the column to the left or the row above your cursor will resize itself.

Pic1 (b).jpg
Pic2 (b).jpg

If there is data in any of the cells in your target column/row, the AutoFit feature will extend so that every cell is showing the entirety of its content.  If the entire row is empty then AutoFit will adjust to your default row height (NOTE: using AutoFit on an empty column will not adjust that column back to its default width).  Pretty cool, huh?

The Problem

Are you a power user of the double-click column/row auto-adjust feature? Well I am and there have been instances where I double-click to AutoFit a row height and Excel does nothing!  After years of being bugged with this, I finally had enough and decided to figure out what was causing me this grief.

Through testing, I discovered that this only occurred when I was trying to readjust merged cells that also had the text wrapping format activated.  Apparently the AutoFit functionality does not work when these two conditions both occur, so you are forced to manually adjust the height until all your characters are showing.

***Side Note - If you have been following my posts, you probably know that I detest the use of merging cells unless absolutely necessary.  Well you've caught me!  I do merge cells in Excel but it is usually in cases where I am putting together a survey or need some sort of long text field added to my spreadsheet.  I almost never merge cells when working on an analysis where someone may need to copy/paste-values my data.

What's The Solution?

So after consulting with my best friend Google, I found a macro that was written by Jim Rech on one of the Excel forums.  I could not find very much information on who Jim is but I sure do like his solution!  I have added a few Error Handlers to Jim’s original code to make it a little more error-proof.  So add this subroutine to your Personal Macro Collection and enjoy!

Sub AutoFitMergedCellRowHeight()

'PURPOSE: Provides a workaround to Autofitting a row that has merged cells in it
'SOURCE: www.TheSpreadsheetGuru.com
'MODIFIED BY: Chris Macro

Dim CurrentRowHeight As Single, MergedCellRgWidth As Single
Dim ActiveCellWidth As Single, PossNewRowHeight As Single
Dim CurrCell As Range
    'Prevent misuse of procedure
        On Error GoTo SelectCell
            If Selection.Rows.Count > 1 Then
                MsgBox "Please select only the merged cell you want to adjust"
                Exit Sub
            End If
        On Error GoTo 0
    'Readjust Row Height
        If ActiveCell.MergeCells Then
           With ActiveCell.MergeArea
                If .Rows.Count = 1 And .WrapText = True Then
                    Application.ScreenUpdating = False
                    CurrentRowHeight = .RowHeight
                    ActiveCellWidth = ActiveCell.ColumnWidth
                        For Each CurrCell In Selection
                            MergedCellRgWidth = CurrCell.ColumnWidth + MergedCellRgWidth
                    .MergeCells = False
                    .Cells(1).ColumnWidth = MergedCellRgWidth
                    PossNewRowHeight = .RowHeight
                    .Cells(1).ColumnWidth = ActiveCellWidth
                    .MergeCells = True
                    .RowHeight = IIf(CurrentRowHeight > PossNewRowHeight, _
                     CurrentRowHeight, PossNewRowHeight)
                End If
            End With
        End If
        Exit Sub
    MsgBox "Make sure a cell is selected before running."
    Exit Sub
End Sub

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it's impossible to account for every particular need one might have. That's why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to getting quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don't have time to fit everyone's questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Chris "Macro" Newman :)