Results 1 to 7 of 7
  1. #1
    Lounger
    Join Date
    Jul 2002
    Location
    Sun Prairie, WI, USA
    Posts
    25
    Thanks
    0
    Thanked 0 Times in 0 Posts

    What's the cell format? (2000)

    Seems like a simple request, but...

    I want to be able to determine which cells in a range have a fill color of yellow. I thought I might be able to use the =CELL() function, but it doesn't appear to go into detail regarding color.

    I thought I might even be able to add a comment to those same cells and count those (would be a pain, but doable). But, alas, the =CELL() function doesn't seem to care about those cells either.

    I suppose I could write a macro that would be able to do this, but I thought I'd ask.
    Thoughts?

  2. #2
    Lounger
    Join Date
    Jul 2002
    Location
    Sun Prairie, WI, USA
    Posts
    25
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: What's the cell format? (2000)

    Thank you so much. This is just what I was looking for.
    Also thanks for the looping code. Very helpful.

    Just for clarification, is the reference to "cell" in your code a Variant? VBA doesn't recognize it as a reserved word, so I assume that it's an undeclared variable.

  3. #3
    Uranium Lounger
    Join Date
    Dec 2000
    Location
    Salt Lake City, Utah, USA
    Posts
    9,508
    Thanks
    0
    Thanked 6 Times in 6 Posts

    Re: What's the cell format? (2000)

    It ends up being a Range, so you can Dim Cell as Range if you want.
    -John ... I float in liquid gardens
    UTC -7ąDS

  4. #4
    Super Moderator
    Join Date
    May 2002
    Location
    Canberra, Australian Capital Territory, Australia
    Posts
    5,054
    Thanks
    2
    Thanked 417 Times in 346 Posts

    Re: What's the cell format? (2000)

    Hi,

    No, there's no inbuilt formula for retrieving a cell's colour. You can do it with a macro, but what you then get is the colour's index #, not a name. Since there's different shades of yellow available, you'd have to know which one you're looking for. The standard yellow's index # is 6. You could use the following macro to count such cells:

    Sub CountYellowCells()
    Dim YellowCount as Integer
    Dim Cell As Range
    YellowCount = 0
    For Each Cell In Selection
    If Cell.Interior.ColorIndex = 6 Then
    YellowCount = YellowCount + 1
    End If
    Next Cell
    MsgBox YellowCount
    End sub


    It occurs to me, however, that the colouring you're using is probably based on a set of criteria. That being so, you should be able to build a formula that tests whether a given cell satisfies those criteria. This can be used in two ways: via conditional formatting to colour such cells; and to pass values to other cells where the results can be acted on.

    Cheers
    Cheers,

    Paul Edstein
    [MS MVP - Word]

  5. #5
    Super Moderator
    Join Date
    May 2002
    Location
    Canberra, Australian Capital Territory, Australia
    Posts
    5,054
    Thanks
    2
    Thanked 417 Times in 346 Posts

    Re: What's the cell format? (2000)

    As John says, it should be DIMmed as a Range. I've updated the post to reflect that, change the range to a selection insead of a named range, and to correct a typo (colorindex, not colourindex).
    Cheers
    Cheers,

    Paul Edstein
    [MS MVP - Word]

  6. #6
    Uranium Lounger
    Join Date
    Jan 2001
    Location
    South Carolina, USA
    Posts
    7,295
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: What's the cell format? (2000)

    This Thread may also be of some use to you.
    Legare Coleman

  7. #7
    3 Star Lounger
    Join Date
    Dec 2000
    Location
    NJ, USA
    Posts
    239
    Thanks
    2
    Thanked 1 Time in 1 Post

    Re: What's the cell format? (2000)

    Another option would be to define functions as follows:
    <pre>Public Function GetColorIndex(ByVal vrngCell As Excel.Range) As Integer
    GetColorIndex = vrngCell.Interior.ColorIndex
    End Function</pre>


    and,
    <pre>Public Function GetColor(ByVal vrngCell As Excel.Range) As String
    Dim lngColor As Long
    Dim lngRed As Long
    Dim lngGreen As Long
    Dim lngBlue As Long

    lngColor = vrngCell.Interior.Color

    lngBlue = Int(lngColor / 256 ^ 2)
    lngGreen = Int((lngColor - lngBlue * 256 ^ 2) / 256)
    lngRed = lngColor - lngBlue * 256 ^ 2 - lngGreen * 256

    GetColor = "RGB(" & lngRed & "," & lngGreen & "," & lngBlue & ")"
    End Function</pre>


    You could then use these functions in the worksheet to return the color values - and use COUNTIF, maybe(?)

Posting Permissions

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