Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Finding Columns of a Certain Width.

Finding Columns of a Certain Width

Written by Allen Wyatt (last updated December 21, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003


Howard has a need to discover all the columns in a worksheet that are a given width. For instance, he needs to know which columns have a width of 3.6.

This can be done by using a macro. One of the properties your macro can access is the width of each column. This means that you can step through the columns and check those widths against the desired width (3.6) in the following manner:

Sub ListColumns()
    Dim dColWidth As Double
    Dim sMsg As String
    Dim x As Integer

    dColWidth = 3.6
    sMsg = ""
    For x = 1 To ActiveSheet.Columns.Count
        If Columns(x).ColumnWidth = dColWidth Then
            sMsg = sMsg & vbCrLf & x
        End If
    Next
    If sMsg = "" Then
        sMsg = "There are no columns with" & _
          vbCrLf & "a width of " & dColWidth
    Else
        sMsg = "The following columns have" & _
          vbCrLf & "a width of " & dColWidth & _
          ":" & vbCrLf & sMsg
    End If
    MsgBox sMsg
End Sub

This macro displays a message box that lists the columns that match the desired width. The macro can be made more robust with some simple changes. For instance, the following example prompts the user for a column width, counts the number of matches, and even compensates if the worksheet is using R1C1 referencing mode.

Sub Find_ColumnWidth()
    Dim Col As Integer          ' Column (loop variable)
    Dim ColsFound As Integer    ' Columns Found Count
    Dim Desired_Width As Double ' Column Width To Find
    Dim OutStr As String        ' Output String
    Dim Title As String         ' Msgbox Title
    Dim I As Integer
    Dim S As String

    ' Find out column width wanted
    S = InputBox("Enter ColumnWidth to find ?", _
      " Find ColumnWidth on " & ActiveSheet.Name)
    Desired_Width = Val(S)
    If Desired_Width = 0 Then Exit Sub

    ' Initialize Columns Found Count and Output String
    ColsFound = 0
    OutStr = ""

    For Col = 1 To ActiveSheet.Columns.Count
        If Columns(Col).ColumnWidth = Desired_Width Then
            ColsFound = ColsFound + 1

            If Application.ReferenceStyle = 1 Then
                ' Using "A1" format
                S = Cells(1, Col).Address(ReferenceStyle:=xlA1)
                S = Mid(S, 2, Len(S) - 3)
            Else
                ' Using "R1C1" format
                S = Trim(Str(Col))
            End If
            OutStr = OutStr & S & vbCrLf
        End If
    Next

    ' Construct MsgBox Title string
    Title = "Width=" & Desired_Width _
      & " on " & ColsFound & " column" _
      & Left("s", - (ColsFound > 1)) & " "

    If ColsFound = 0 Then
        OutStr = "No matches found"
    End If

    MsgBox OutStr, vbOKOnly, Title
End Sub

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3827) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding Columns of a Certain Width.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Attaching Macros to Documents

When you distribute documents to other people, you may want those documents to have associated macros that the reader can ...

Discover More

Fitting Your Printout on a Page

Tired of wasting paper when you print a worksheet? You can scale Excel's output so that it fits only the number of pages ...

Discover More

Counting Lists

Word makes it easy to add both numbered lists and bulleted lists to your document. If you are working with longer ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (menu)

Finding Workbooks Containing Macros

Workbooks can contain macros, or not. It is entirely up to you whether they do or not, but at some future time you might ...

Discover More

Quickly Dumping Array Contents

Variable arrays are used quite often in macros. If you use an array once in your macro and then need to reuse it for ...

Discover More

Debugging a Macro

Part of writing macros is to make sure they work as you expect. This involves a process known as debugging. Here's how ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 9 - 3?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.