I have a worksheet in Excel. Now I need to know if I have to adjust
cellwidths (or height) to get all text to fit in the cells.
I can't use AutoFit as it doesn't work with merged cells (ms article:
Q212010).
I tried to do this with API, but it doesn't give me an accurate respons.
Here's my testcode:
Sub TestFont()
Dim font As LOGFONT
Dim prevFont As Long, hFont As Long, ret As Long
Dim hWnd As Long, hdc As Long
Dim vStr_Txt As String, vLng_X As Long
Dim lpSize As Size, RetVal As Long
'Device context to active object
hWnd = GetFocus()
hdc = GetDC(hWnd)
'Font-data (fontsize in pixels)
font.lfFaceName = Range("C8").font.Name & Chr$(0)
font.lfHeight = -MulDiv((Range("C8").font.Size), GetDeviceCaps(hdc,
LOGPIXELSY), 72)
'Creates temporary Font
hFont = CreateFontIndirect(font)
If hFont = 0 Then Exit Sub
prevFont = SelectObject(hdc, hFont)
'Width of text in specified cell
vStr_Txt = Range("C8") & ""
RetVal = GetTextExtentPoint32(hdc, vStr_Txt, Len(vStr_Txt), lpSize)
MsgBox "Textwidth:" & lpSize.cx
'Width of specified cell
vLng_X = ActiveWorkbook.ActiveSheet.Range("C8").Width
MsgBox "Cellwidth: " & MulDiv((vLng_X), GetDeviceCaps(hdc, LOGPIXELSX),
72)
'Restores.
ret = SelectObject(hdc, prevFont)
ret = DeleteObject(hFont)
End Sub
When I've tried this I've set the text to "Test" and then used the
autofit-function to adjust width of cell.
The textwidth shows 38 pixels, but the cellwidth shows 47.
If I set the cellwidth to 38, the text fits exactly. But if I do the same
thing with a number, the cell only shows the character #.
Is there any way to know how much extra space excel needs to show numbers?
Is it a fixed width in Excel that I can use?
Help would be much appreciated
Daniel
''Simulates row height autofit for a merged cell if the active cell..
'' is merged.
'' has Wrap Text set.
'' includes only 1 row.
''Unlike real autosizing the macro only increases row height
'' (if needed). It does not reduce row height because another
'' merged cell on the same row may needed a greater height
'' than the active cell.
Sub AutoFitMergedCellRowHeight()
Dim CurrentRowHeight As Single, MergedCellRgWidth As Single
Dim CurrCell As Range
Dim ActiveCellWidth As Single, PossNewRowHeight As Single
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
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
End If
End Sub
--
Jim Rech
Excel MVP
/Daniel
Sub AutoFitMergedCellRowHeight()
Dim CurrentRowHeight As Single, MergedCellRgWidth As Single
Dim CurrCell As Range, RangeWidth As Single
Dim ActiveCellWidth As Single, PossNewRowHeight As Single
If ActiveCell.MergeCells Then
With ActiveCell.MergeArea
If .Rows.Count = 1 And .WrapText = True Then
Application.ScreenUpdating = False
CurrentRowHeight = .RowHeight
ActiveCellWidth = ActiveCell.ColumnWidth
RangeWidth = .Width
For Each CurrCell In Selection
MergedCellRgWidth = CurrCell.ColumnWidth +
MergedCellRgWidth
Next
.MergeCells = False
.Cells(1).ColumnWidth = MergedCellRgWidth
While .Cells(1).Width < RangeWidth
.Cells(1).ColumnWidth = .Cells(1).ColumnWidth + 0.5
Wend
.Cells(1).ColumnWidth = .Cells(1).ColumnWidth - 0.5