Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

XL2000: How to Use Macros to Set Row Height and Column Width


View products that this article applies to.

This article was previously published under Q213422

↑ Back to the top


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 or centimeters without trial and error.

Excel bases its measurement of column widths on the number of digits (specifically, the number of zeros) in the column, using the Normal style font. (There are some fonts that have digits of different widths, but this is unusual.)

For example, using the default font, a column with a width of 10 refers to the column width needed to display 10 non-bold, non-italic, Arial 10-point zeros. On a Macintosh computer, this same column width consists of 10 non-bold, non-italic Geneva 10-point zeros. 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 the specified 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.

This article provides sample Microsoft Visual Basic for Applications macros that allow you to set the row height and column width in either inches or centimeters.

↑ Back to the top


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 Partner or Microsoft Advisory Services. For more information, visit these Microsoft Web sites:

Microsoft Certified Partners - https://partner.microsoft.com/global/30000104

Microsoft Advisory Services - http://support.microsoft.com/gp/advisoryservice

For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMS Use the following Visual Basic for Applications macros to specify the row and column widths in inches.
Sub RowHeightInInches()
    Dim inches As Single
    ' 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 Single, 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

				
Use the following macros to specify the row and column widths in centimeters.
Sub RowHeightInCentimeters()
    Dim cm As Single
    ' 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 Single, 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
				

↑ Back to the top


References

For additional information about getting help with Visual Basic for Applications, click the article number below to view the article in the Microsoft Knowledge Base:
226118� OFF2000: Programming Resources for Visual Basic for Applications

↑ Back to the top


Keywords: KB213422, kbualink97, kbprogramming, kbinfo, kbhowto, kbdtacode

↑ Back to the top

Article Info
Article ID : 213422
Revision : 8
Created on : 11/23/2006
Published on : 11/23/2006
Exists online : False
Views : 292