If text length <65 then rowheight = 14

nitrammada

Board Regular
Joined
Oct 10, 2018
Messages
78
Office Version
  1. 365
Platform
  1. Windows
Hi Friends,
Does anyone know the VBA to see if the length of a string within a cell is <65. If yes, then make the row height 14, Else wrap the text and add a space of +2?
The +2 is to give a little white space for clarity of reading before the next cell / line of text starts.
I'm wanting to test every cell in column L of the active sheet.
Any help would be appreciated.
Regards
Adam
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Not sure what you mean by 'add a space of + 2', but the following should perform the other stuff mentioned:

VBA Code:
Sub SetRowHeightOrWrapText()
'
    Dim ColumnRow           As Long
    Dim LastRowInColumnL    As Long
'
    LastRowInColumnL = Range("L" & Rows.Count).End(xlUp).Row        ' Get last row in column L

    For ColumnRow = 1 To LastRowInColumnL                           ' Loop to loop through the L column
        If Len(Range("L" & ColumnRow).Value) < 65 Then              '   If Length of cell value < 65 then ...
            Rows(ColumnRow & ":" & ColumnRow).RowHeight = 14        '       Set the row height for that row to 14
        Else                                                        '   Else
            Range("L" & ColumnRow).WrapText = True                  '       Set that cell to WrapText
        End If
    Next                                                            ' Loop back
End Sub
 
Upvote 0
How about
VBA Code:
Sub nitrammada()
   Dim Cl As Range
   
   For Each Cl In Range("L1", Range("L" & Rows.Count).End(xlUp))
      If Len(Cl.Value) < 65 Then
         Cl.RowHeight = 14
      Else
         Cl.WrapText = True
         Cl.RowHeight = Cl.RowHeight + 2
      End If
   Next Cl
End Sub
 
Upvote 0
Not sure what you mean by 'add a space of + 2', but the following should perform the other stuff mentioned:

VBA Code:
Sub SetRowHeightOrWrapText()
'
    Dim ColumnRow           As Long
    Dim LastRowInColumnL    As Long
'
    LastRowInColumnL = Range("L" & Rows.Count).End(xlUp).Row        ' Get last row in column L

    For ColumnRow = 1 To LastRowInColumnL                           ' Loop to loop through the L column
        If Len(Range("L" & ColumnRow).Value) < 65 Then              '   If Length of cell value < 65 then ...
            Rows(ColumnRow & ":" & ColumnRow).RowHeight = 14        '       Set the row height for that row to 14
        Else                                                        '   Else
            Range("L" & ColumnRow).WrapText = True                  '       Set that cell to WrapText
        End If
    Next                                                            ' Loop back
End Sub
Hi JohnnyL, thank you so much for you response. It works and reduces the row height to 14 for text less than 65, great work, thank you. And it does wrap for text >65 however, the row height does not expand to show the wrapped text, the row height remains at it's original height, does that seem strange to you?
 
Upvote 0
How about
VBA Code:
Sub nitrammada()
   Dim Cl As Range
  
   For Each Cl In Range("L1", Range("L" & Rows.Count).End(xlUp))
      If Len(Cl.Value) < 65 Then
         Cl.RowHeight = 14
      Else
         Cl.WrapText = True
         Cl.RowHeight = Cl.RowHeight + 2
      End If
   Next Cl
End Sub
Hi Fluff, thank you again for coming to my aid. I ran the code but it seems to hang for some reason, I get the spinning wheel for a few minutes, i eventually hit the escape key to stop the code. I tried stepping into the code and it works for cells with text <65 and changes the row height to 14 but doesn't do anything for the other text >65, any thoughts what may be cause that. It seems like it is half way there.
 
Upvote 0
When you step through the code does it go to this line?
VBA Code:
         Cl.WrapText = True
 
Upvote 0
Hi JohnnyL, thank you so much for you response. It works and reduces the row height to 14 for text less than 65, great work, thank you. And it does wrap for text >65 however, the row height does not expand to show the wrapped text, the row height remains at it's original height, does that seem strange to you?

Try this:

VBA Code:
Sub SetRowHeightOrWrapTextV2()
'
    Dim ColumnRow           As Long
    Dim LastRowInColumnL    As Long
'
    LastRowInColumnL = Range("L" & Rows.Count).End(xlUp).Row        ' Get last row in column L

    For ColumnRow = 1 To LastRowInColumnL                           ' Loop to loop through the L column
        If Len(Range("L" & ColumnRow).Value) < 65 Then              '   If Length of cell value < 65 then ...
            Rows(ColumnRow & ":" & ColumnRow).RowHeight = 14        '       Set the row height for that row to 14
        Else                                                        '   Else
            Range("L" & ColumnRow).WrapText = True                  '       Set that cell to WrapText
            Range("L" & ColumnRow).Rows.AutoFit                     '       Resize row height to display wrapped text
        End If
    Next                                                            ' Loop back
End Sub
 
Upvote 0
When you step through the code does it go to this line?
VBA Code:
         Cl.WrapText = True
Yes, it will step into that line, it will wrap the text but the row height does not adjust. There are some blank cells in column L, I was wondering if that would cause a problem some how. Whilst it is column L that needs to be formatted, a better index column would be column C because every row has a row number whether it has text in it or not. So I was thinking of adjusting the code to this:
VBA Code:
   For Each Cl In Range("L1", Range("C" & Rows.Count).End(xlUp))
I ran the code with the adjustment as per above but it did not make any difference, it still fell over.
 
Upvote 0
Ok, how about
VBA Code:
Sub nitrammada()
   Dim Cl As Range
   
   For Each Cl In Range("L6", Range("L" & Rows.Count).End(xlUp))
      If Len(Cl.Value) < 65 Then
         Cl.RowHeight = 14
      Else
         Cl.WrapText = True
         Cl.EntireRow.AutoFit
         Cl.RowHeight = Cl.RowHeight + 2
      End If
   Next Cl
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,213,486
Messages
6,113,932
Members
448,533
Latest member
thietbibeboiwasaco

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