XL: Macros to Set Row Height and Column Width
ID: Q130050
|
The information in this article applies to:
-
Microsoft Excel 98 Macintosh Edition
-
Microsoft Excel 97 for Windows
-
Microsoft Excel for Windows 95, versions 7.0, 7.0a
-
Microsoft Excel for Windows, versions 5.0, 5.0c
-
Microsoft Excel for the Macintosh, versions 5.0, 5.0a
-
Microsoft Excel for Windows NT, version 5.0
SUMMARY
Microsoft Excel uses the font assigned in the Normal style as the basis for
column widths. There is no direct way to assign exact column widths in
inches/centimeters without trial and error.
Microsoft Excel uses the number of digits (specifically, the number of
zeros) using the Normal style font as the measurement to determine column
widths. (There are some fonts that have digits of different widths, but
this is unusual.)
For example, using the default font, a column width of 10 means the
column width needed to display 10 non-bold, non-italic, Arial 10-point
zeros. On the Macintosh, this same column width is 10 non-bold, non-italic Geneva 10-point zeros. Microsoft Excel uses digits to determine
column widths so that when you change the font for a style on a worksheet,
the columns grow or shrink to display this number of digits in the column.
Note that this method of determining column widths is not "exact" when you
use other characters, such as spaces, dollar signs, parentheses, and so on.
Also, because the variables below are dimensioned as Integer, these procedures work with whole numbers only. You can dimension these variables as Double to work with fractional measures. For example, changing
Dim inches as Integer
to
Dim inches as Double
dimensions the variable inches as a double-precision variable.
This article provides sample Microsoft Visual Basic for Applications
macros (Sub procedures) that allow you to set row height and column width in either inches or centimeters.
MORE INFORMATION
Microsoft provides programming examples for illustration only, without warranty
either expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes that you
are familiar with the programming language being demonstrated and the tools used to
create and debug procedures. Microsoft support professionals can help explain the functionality
of a particular procedure, but they will not modify these examples to provide added
functionality or construct procedures to meet your specific needs. If you have limited
programming experience, you may want to contact a Microsoft Certified Solution Provider
or the Microsoft fee-based consulting line at (800) 936-5200. For more information about
Microsoft Certified Solution Providers, please see the following page on the World Wide Web:
http://www.microsoft.com/mcsp/
For more information about the support options available from Microsoft, please see the
following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp
The following Visual Basic for Applications procedures allow you to specify the row and column widths in inches:
Sub RowHeightInInches()
Dim inches as Integer
' Get the desired column width.
inches = Application.InputBox("Enter Row Height in Inches", _
"Row Height (Inches)", Type:=1)
' If the cancel button was not pressed.
If inches Then
' Convert and set the column height.
Selection.RowHeight = Application.InchesToPoints(inches)
End If
End Sub
Sub ColumnWidthInInches()
Dim inches As Integer, points As Integer, savewidth As Integer
Dim lowerwidth As Integer, upwidth As Integer, curwidth As Integer
Dim Count As Integer
' Turn screen updating off.
Application.ScreenUpdating = False
' Ask for the desired width in inches.
inches = Application.InputBox("Enter Column Width in Inches", _
"Column Width (Inches)", Type:=1)
' If the cancel button for the input box is pressed, exit the
' procedure.
If inches = False Then Exit Sub
' Convert the entered inches to points.
Points = Application.InchesToPoints(inches)
' Save the current column width setting.
savewidth = ActiveCell.ColumnWidth
' Set the column width to the maximum allowed.
ActiveCell.ColumnWidth = 255
' If points wanted is greater than points for 255 characters.
If Points > ActiveCell.Width Then
' Display a message box (the specified size is too large), and
' let user know maximum allowed value.
MsgBox "Width of " & inches & " is too large." & Chr(10) & _
"The maximum value is " & Format(ActiveCell.Width / 72, _
"0.00"), vbOKOnly + vbExclamation, "Width Error"
' Reset the column width back to the original.
ActiveCell.ColumnWidth = savewidth
' Exit out of the Sub from here.
Exit Sub
End If
' Set the lowerwidth and upperwidth variables.
lowerwidth = 0
upwidth = 255
' Set the column width to the middle of the allowed character range.
ActiveCell.ColumnWidth = 127.5
curwidth = ActiveCell.ColumnWidth
' Set the count to 0 so if it can't find an exact match it won't go
' indefinitely.
Count = 0
' Loop as long as the cell width is different from width desired
' and the count (iterations) of the loop is less than 20.
While (ActiveCell.Width <> Points) And (Count < 20)
' If active cell width is less than desired cell width.
If ActiveCell.Width < Points Then
' Reset lower width to current width.
lowerwidth = curwidth
' Set current column width to the midpoint of curwidth and
' upwidth.
Selection.ColumnWidth = (curwidth + upwidth) / 2
' If active cell width is greater than desired width.
Else
' Set upwidth to the curwidth.
upwidth = curwidth
' Set column width to the mid point of curwidth and lower
' width.
Selection.ColumnWidth = (curwidth + lowerwidth) / 2
End If
' Set curwidth to the width of the column now.
curwidth = ActiveCell.ColumnWidth
' Increment the count counter.
Count = Count + 1
Wend
End Sub
The following Visual Basic for Applications procedures allow you to specify the row and column widths in centimeters:
Sub RowHeightInCentimeters()
Dim cm As Integer
' Get the row height in centimeters.
cm = Application.InputBox("Enter Row Height in Centimeters", _
"Row Height (cm)", Type:=1)
' If cancel button not pressed and a value entered.
If cm Then
' Convert and set the row height
Selection.RowHeight = Application.CentimetersToPoints(cm)
End If
End Sub
Sub ColumnWidthInCentimeters()
Dim cm As Integer, points As Integer, savewidth As Integer
Dim lowerwidth As Integer, upwidth As Integer, curwidth As Integer
Dim Count As Integer
' Turn screen updating off.
Application.ScreenUpdating = False
' Ask for the width in inches wanted.
cm = Application.InputBox("Enter Column Width in Centimeters", _
"Column Width (cm)", Type:=1)
' If cancel button for the input box was pressed, exit procedure.
If cm = False Then Exit Sub
' Convert the inches entered to points.
Points = Application.CentimetersToPoints(cm)
' Save the current column width setting.
savewidth = ActiveCell.ColumnWidth
' Set the column width to the maximum allowed.
ActiveCell.ColumnWidth = 255
' If the points desired is greater than the points for 255
' characters...
If Points > ActiveCell.Width Then
' Display a message box because the size specified is too
' large and give the maximum allowed value.
MsgBox "Width of " & cm & " is too large." & Chr(10) & _
"The maximum value is " & _
Format(ActiveCell.Width / 28.3464566929134, _
"0.00"), vbOKOnly + vbExclamation, "Width Error"
' Reset the column width back to the original.
ActiveCell.ColumnWidth = savewidth
' Exit the Sub.
Exit Sub
End If
' Set the lowerwidth and upper width variables.
lowerwidth = 0
upwidth = 255
' Set the column width to the middle of the allowed character
' range.
ActiveCell.ColumnWidth = 127.5
curwidth = ActiveCell.ColumnWidth
' Set the count to 0 so if it can't find an exact match it won't
' go on indefinitely.
Count = 0
' Loop as long as the cell width in is different from width
' wanted and the count (iterations) of the loop is less than 20.
While (ActiveCell.Width <> Points) And (Count < 20)
' If active cell width is less than desired cell width.
If ActiveCell.Width < Points Then
' Reset lower width to current width.
lowerwidth = curwidth
' set current column width to the midpoint of curwidth
' and upwidth.
Selection.ColumnWidth = (curwidth + upwidth) / 2
' If active cell width is greater than desired cell width.
Else
' Set upwidth to the curwidth.
upwidth = curwidth
' Set column width to the mid point of curwidth and lower
' width.
Selection.ColumnWidth = (curwidth + lowerwidth) / 2
End If
' Set curwidth to the width of the column now.
curwidth = ActiveCell.ColumnWidth
' Increment the count counter.
Count = Count + 1
Wend
End Sub
Additional query words:
XL98 XL97 XL7 XL5 howto
Keywords : kbprg kbualink97 kbdta kbdtacode PgmHowto KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0,7.0a,97; winnt:5.0
Platform : MACINTOSH WINDOWS winnt
Issue type : kbhowto