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: Alphabetic Column Designation.

Alphabetic Column Designation

by Allen Wyatt
(last updated February 7, 2015)

You can easily determine the numeric column of cell by using the COLUMN function. All you need to do is put a formula like this in a cell, and the result is a value where A=1, B=2, etc.:

=COLUMN()

What if you want an alphabetic value, rather than a numeric value? This can be done in any of several different ways. For instance, the following formula will work very nicely for the first 26 columns, A through Z:

=CHAR(COLUMN()+64)

This works because the letters A through Z use character codes 65 through 90. When COLUMN returns a value for columns A through Z (1 through 26), this can be added to 64 to get the letters of those columns, 65 through 90.

Of course, this solution won't work if you want to know the letter designations of columns beyond Z. (Excel can use columns up through IV.) This formula will work for single- and double-character columns:

=IF(COLUMN()<27,CHAR(COLUMN()+64),CHAR((COLUMN()/26)+64)&
CHAR(MOD(COLUMN(),26)+64))

As you can tell, when you get into multiple characters for a column, the formula gets long rather quickly. You can make the formula shorter by using a function other than COLUMN, however. Consider this formula, which relies primarily upon the ADDRESS function:

=LEFT(ADDRESS(1,COLUMN(),4),(COLUMN()>26)+1)

The ADDRESS function returns the address of a specific cell. In this case, it returns the address for the cell in the first row of the current column. Thus, if the formula is in cell BF27, it returns BF1. The formula uses the LEFT function to return the correct number of left-most characters in the address, minus the number 1 for the row.

An even shorter version of the formula relies upon the SUBSTITUTE function instead of the LEFT function:

=SUBSTITUTE(ADDRESS(ROW(),COLUMN(),4),ROW(),"")

This version uses the ROW function to put the address together, and then strips the ROW value out of the result of the ADDRESS function.

Of course, you can also use a macro-based solution, if you want to. The follow macro will work with any column in your worksheet:

Function AlphaCol() As String
    Dim J As Integer
    Dim K As Integer
    Dim iDiv As Integer
    Dim sTemp As String

    Application.Volatile
    J = Selection.Column
    iDiv = 26 ^ 2
    sTemp = ""
    While J > 0
        K = Int(J / iDiv)
        If K > 0 Then sTemp = sTemp & Chr(K + 64)
        J = J - (K * iDiv)
        iDiv = iDiv / 26
    Wend
    AlphaCol = sTemp
End Function

The macro is a user-defined function, which means that you can use it in your worksheets by simply adding this to any cell:

=AlphaCol()

A text string is returned, consisting of the column designation.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3254) 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: Alphabetic Column Designation.

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

Viewing Same Cells on Different Worksheets

When switching from one worksheet to another, you might want to view the same portion of the new worksheet that you were ...

Discover More

Reusing a Bookmark

Bookmarks in Word are just like bookmarks used in paper books, any given bookmark may be reused to mark a new location. ...

Discover More

Finding an Optimal Table Height

Word can adjust the height of individual rows in a table based on the information you put in each row. This may not result in ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

MORE EXCELTIPS (MENU)

Viewing Formula Results

When editing information in a cell, you may need to know the result of a portion of your formula. The shortcut described in ...

Discover More

Finding the First Non-Digit in a Text Value

If you have a string of text that is composed of digits and non-digits, you may want to know where the digits stop and the ...

Discover More

Adding Ordinal Notation to Dates

Want to add an ordinal suffix to a number, as in 2nd, 3rd, or 4th? Excel doesn't provide a way to do it automatically, but ...

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 for this tip:

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.

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.

Links and Sharing
Share