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

Written by Allen Wyatt (last updated July 8, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003


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.

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 (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

Easily Deploying Customizations

When you create a whole set of customizations for Excel, you may want to share them with others in your office or ...

Discover More

Is It Worth Converting Data to a Table?

Excel allows you to work with your data in many different ways. One way is to convert your data to a structured table. ...

Discover More

Storing Macros in Templates

How Excel uses templates is different than how Word uses templates. This tip looks at those differences and discusses ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (menu)

Understanding Operators

At the heart of working with Excel is the process of creating formulas that calculate results based on information within ...

Discover More

Incrementing References by Multiples when Copying Formulas

You can easily set up a formula to perform some calculation on a range of cells. When you copy that formula, the copied ...

Discover More

Averaging the Last Numbers in a Column

Need to calculate a running average for the last twelve values in a constantly changing range of values? The formula ...

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 8 + 7?

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.