Results 1 to 2 of 2
  1. #1
    New Lounger
    Join Date
    Dec 2003
    Location
    Luton, Bedfordshire, England
    Posts
    3
    Thanks
    0
    Thanked 0 Times in 0 Posts

    NEW Get Excel Column Routine (v1.0)

    'Having tested many routines that convert an integer to "column letter" - and all on offer failed - and are of massive coding
    'here a routine, that works 100% from 1="A" to 702 ="ZZ". It nearly become a One-Line-Code. Somehow Excel doesn't like
    'a nested IIF() statement - however - this one is worth to be "FREEWARE" - so enjoy the little code sample, and let me know
    'if someone has an improvement - I would rather like a One-Liner.

    Public Function GetExcelColumn(ByVal colNumber As Integer) As String

    ' with complimants from Bernd Hallmann Dec 2003

    '<-------------------- remove the checking code if necessary and to run upto "ZZ"
    if colNumber = 0 or colNumber > 256 then 'MAX 702="ZZ"
    msgbox "Range from 1 to 256 only, current value" & str(colNumber),vbokonly + vbinformation,"Error"
    GetExcelColumn = ""
    exit function
    endif
    '--------------------------------------------------------------------------------------------------->!

    Select Case colNumber
    Case Is < 27

    ' values (1-26) --> A-Z
    GetExcelColumn = Chr$(colNumber + 64)

    Case Else

    ' values (27-702) --> AA-ZZ
    GetExcelColumn = IIf(colNumber 26 > 0 And colNumber Mod 26 > 0, Chr(colNumber 26 + 64) & Chr(colNumber Mod 26 + 64), Chr(colNumber 26 + 63) & "Z")

    End Select

    End Function

  2. #2
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts

    Re: NEW Get Excel Column Routine (v1.0)

    If you really want 1 line:

    <pre>Function ColHeading(rng As Range) As String
    ColHeading = IIf(rng.Cells(1).Column <= 26, "", _
    Chr(Int((rng.Cells(1).Column - 1) / 26) + 64)) & _
    Chr((rng.Cells(1).Column - 1) Mod 26 + 65)
    End Function</pre>


    Though I prefer the 3 line version:

    <pre>Function ColHeading(rng As Range) As String
    Dim iCol As Integer
    iCol = rng.Cells(1).Column - 1
    ColHeading = IIf(iCol < 26, "", _
    Chr(Int(iCol / 26) + 64)) & _
    Chr(iCol Mod 26 + 65)
    End Function</pre>


    You can even do it with a formula, instead of UDF if you don't want the macro warning:
    <pre>=IF(COLUMN()<=26,"",CHAR(INT((COLUMN()-1)/26)+64))&CHAR(MOD(COLUMN()-1,26)+65)</pre>


    There is no need to get to 702(ZZ), there are only 256 columns (IV)
    Steve

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •