Autofit row height to display wrapped text

FrankB

New Member
Joined
Sep 3, 2002
Messages
31
Hi,

Some lines of the wrapped multiline text don't appear in the cell. Is there any way to autofit the row height of all rows in the worksheet to display the entire text? Doubleclicking below the row narrows the row to cut off text, only dragging each row down individually works. Any ideas?

Thanks,

Frank
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Hi, you have enabled wrapping on the cells? eg Format|Cells|Alignment|Wrap text. Excel will only show about 1000 characters in any one cell athough it can hold much more per cell.

hth
 
Upvote 0
Yeah, wrapping is enabled and the problem is not caused by having too many characters in a cell, as it happens with just a few lines. For some reason, some of the lines on the bottom get cut off when printing, once I go in and drag the row height manually and leave a little extra room, they can be seen. I would like to automate the manual drag part, but double-clicking on the row doesn't work. Any ideas? The font is Arial, in case that matters.

Thanks,

Frank
 
Upvote 0
Ok,
I solved the problem: The font size was 7.5 and I guess there is some issue with drivers and decimals, so I increased it to an integer (8), and now the autoformat works. Hope this helps someone else as well.
 
Upvote 0
I am using Excel 2000 and am having this problem. Wrap Text is on, Font size is a whole number, the only thing I noticed that is different is that the the text is in merged cells. If I unmerge the cells, the autofit row height works okay. I merge the cells and then autofit doesn't work. Any ideas?

And may I take a second to thank all of you! You have saved me sooo much time and aggravation with all your help - much appreciated!
 
Upvote 0
Hi, Ive never noticed this problem before but yes it seems AutoFit, either by double clicking or by using this property in code, doesnt re-adjust the cell height correctly.

However, this code here seems to work. Place the code in a standard module then select the offending cells and run the macro.

hth
 
Upvote 0
Thank you Parry -- I got this to work and as a newbie, I am thrilled! However, it seems that you have to find the merged cell, run the macro, then find the next merged cell, run the macro etc.

Since I have to find the merged cell, it's just as easy to manually change the row height. You wouldn't happen to know of code that will find the merged cells and then run the macro?

Thank you!
 
Upvote 0
Hi Cathyo, replace the above code with this version. Just select the sheet in question then run the macro and this should fix all merged cells in the sheet. Try on a copy of your book first in case there are problems.

Code:
Sub AutoFitMergedCellRowHeight()
    Dim CurrentRowHeight As Single, MergedCellRgWidth As Single
    Dim CurrCell As Range
    Dim ActiveCellWidth As Single, PossNewRowHeight As Single
    Dim StartCell As Range, c As Range, MergeRng As Range, Cell As Range
    Dim a() As String, isect As Range, i

    
'Take a note of current active cell
Set StartCell = ActiveCell

'Create an array of merged cell addresses that have wrapped text
For Each c In ActiveSheet.UsedRange
If c.MergeCells Then
    With c.MergeArea
    If .Rows.Count = 1 And .WrapText = True Then
        If MergeRng Is Nothing Then
            Set MergeRng = c.MergeArea
            ReDim a(0)
            a(0) = c.MergeArea.Address
        Else
        Set isect = Intersect(c, MergeRng)
            If isect Is Nothing Then
                Set MergeRng = Union(MergeRng, c.MergeArea)
                ReDim Preserve a(UBound(a) + 1)
                a(UBound(a)) = c.MergeArea.Address
            End If
        End If
    End If
    End With
End If
Next c


Application.ScreenUpdating = False

'Loop thru merged cells
For i = 0 To UBound(a)
Range(a(i)).Select
      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
                Next
                .MergeCells = False
                .Cells(1).ColumnWidth = MergedCellRgWidth
                .EntireRow.AutoFit
                PossNewRowHeight = .RowHeight
                .Cells(1).ColumnWidth = ActiveCellWidth
                .MergeCells = True
                .RowHeight = IIf(CurrentRowHeight > PossNewRowHeight, _
                  CurrentRowHeight, PossNewRowHeight)
            End If
        End With
MergedCellRgWidth = 0
Next i

StartCell.Select
Application.ScreenUpdating = True

'Clean up
Set CurrCell = Nothing
Set StartCell = Nothing
Set c = Nothing
Set MergeRng = Nothing
Set Cell = Nothing

End Sub
 
Upvote 0
I know it's been a while since anyone posted to this, but I had to add to it because it has just fixed a problem that I have had for months. And I wanted to say Thanks!!!

Also, I found a limitation that I wanted other people to know about so they don't run into the same problem. The limitation is an error that pops up if the total length of the merged cells is more than 255 characters. It appears that that is the maximum length of a single cell. I have found a partial fix.

Change this:
Code:
For Each CurrCell In Selection 
       MergedCellRgWidth = CurrCell.ColumnWidth + MergedCellRgWidth 
Next

To this:
Code:
For Each CurrCell In Selection
    MergedCellRgWidth = CurrCell.ColumnWidth + MergedCellRgWidth
      
      If MergedCellRgWidth > 255 Then
            MergedCellRgWidth = 255
      End If
Next

This might make the row height a little more than what it should be, but it bypasses the error.

Thanks again, I hope this helps someone else. :bow:
 
Upvote 0
Hi Chead5, thank you for taking the time to advise issues with the code. Could you advise what the error is and which line is highlighted when you click debug. There may be other ways to resolve the issue. :-)
 
Upvote 0

Forum statistics

Threads
1,224,061
Messages
6,176,150
Members
452,707
Latest member
laplajewelry

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top