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.
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:
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.
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!
Finding the maximum value in a range of cells is easy; finding the address of the cell containing that value is a ...
Discover MoreWhen you've got a column full of names, you may want to get a count of how many of those names are unique. You can make ...
Discover MoreExcel is usually more flexible in what you can reference in formulas than is immediately apparent. This tip examines some ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments