Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Determining the RGB Value of a Color.

Determining the RGB Value of a Color

Written by Allen Wyatt (last updated July 17, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


9

Neil uses colors a lot in his worksheets. He knows that he can generate a color based upon a numeric RGB value (as explained in other ExcelTips issues). Neil would like to do the opposite—determine an RGB value. He wonders if there is a way to return (via function or macro) the RGB value of the color used to fill a cell. (Neil wants the actual color applied to the cell, not any "override" color, such as one imposed by a conditional format.)

Excel doesn't include a function to do this, but if you only need to check out the RGB values for a single cell, the easiest way is to follow these steps:

  1. Select the cell that is formatted with the color you want to check.
  2. Display the Home tab of the ribbon.
  3. Click the down-arrow at the right side of the Fill Color tool, in the Font group. Excel displays a small palette of colors and some other options.
  4. Choose More Colors. Excel displays the Colors dialog box.
  5. Make sure the Custom tab is displayed. (See Figure 1.)
  6. Figure 1. The Custom tab of the Colors dialog box.

  7. At the bottom of the dialog box you can see the individual values for the red, green, and blue components of the color in the cell.
  8. Click OK when done.

If you have a need to get the values more often, then creating your own user-defined function is the way to go. The function you use depends on what you want to actually have returned to your worksheet. For instance, if you want to have the traditional six-character hex code for RGB colors returned, you would use the following very simple macro:

Function getRGB1(rcell) As String
    Dim sColor As String

    sColor = Right("000000" & Hex(rcell.Interior.Color), 6)
    getRGB1 = Right(sColor, 2) & Mid(sColor, 3, 2) & Left(sColor, 2)
End Function

This macro looks at the interior color for any cell you reference, puts the hex values for the color in the right order, and returns the string to Excel. To use the function you simply invoke it, in your worksheet, with a cell referenced in this manner:

=getRGB1(B4)

You may not want the traditional hex codes for the RGB colors, however. If you want to get the decimal values for each of the colors, then the following macro returns that:

Function getRGB2(rcell) As String
    Dim C As Long
    Dim R As Long
    Dim G As Long
    Dim B As Long

    C = rcell.Interior.Color
    R = C Mod 256
    G = C \ 256 Mod 256
    B = C \ 65536 Mod 256
    getRGB2 = "R=" & R & ", G=" & G & ", B=" & B
End Function

Invoked the same way as the getRGB1 macro, this version returns a string such as "R=255, G=204, B=0". You can also modify the macro even further so that it returns a single value, based upon a parameter you set:

Function getRGB3(rcell As Range, Optional opt As Integer) As Long
    Dim C As Long
    Dim R As Long
    Dim G As Long
    Dim B As Long

    C = rcell.Interior.Color
    R = C Mod 256
    G = C \ 256 Mod 256
    B = C \ 65536 Mod 256

    If opt = 1 Then
        getRGB3 = R
    ElseIf opt = 2 Then
        getRGB3 = G
    ElseIf opt = 3 Then
        getRGB3 = B
    Else
        getRGB3 = C
    End If
End Function

To use the macro, simply add a second parameter to the function used in your worksheet, specifying what you want:

=getRGB3(B4,1)

If the second parameter is 1, then the function returns just the red value. If you specify a second parameter of 2, then the green value is returned, and 3 returns the blue value. Any other value for the second parameter (or if you omit it entirely) returns the full decimal value of the interior color.

If you don't want to go the route of creating a macro, or if you want to determine colors in more than just your Excel worksheet, you might consider a third-party utility. One that looks interesting is Instant Eyedropper, which is free. You can find more information about it here:

http://instant-eyedropper.com

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 (10180) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Determining the RGB Value of a Color.

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

Determining a Value of a Cell

Cells can store all sorts of information that can be formatted and displayed in a myriad of ways. If you want to quickly ...

Discover More

Changing the Underline Color

Word provides quite a bit of latitude when it comes to formatting your underlines. This tip looks at how to best change ...

Discover More

Disappearing Column Formatting

Two things go into making your documents look just right: content and formatting. If the formatting seems to disappear on ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Comparing Strings

As your macro is processing information, there will doubtless be times that it will need to compare information in ...

Discover More

Copying Worksheets in a Macro

Copying worksheets (one or many) is easy to do manually. What is not well known is that it is even easy to make the ...

Discover More

Running a Procedure when a Workbook is Opened

Ever want to have Excel run a procedure whenever you open a workbook? It's not as difficult as you might think. Here's how.

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 three less than 3?

2024-07-06 10:25:36

J. Woolley

For more on this subject, see my comment here: https://excelribbon.tips.net/T009092


2021-07-22 15:10:47

Brian

Differently

Function R(cell As Range)
R = cell.Interior.Color Mod 256
End Function
Function G(cell As Range)
G = cell.Interior.Color \ 256 Mod 256
End Function
Function B(cell As Range)
B = cell.Interior.Color \ 256 ^ 2 Mod 256
End Function
Function rgb(cell As Range)
rgb = Join(Array(R(cell), G(cell), B(cell)), ",")
End Function


2021-07-22 14:26:19

Brian

Shorter
Function getRGB4(rcell As Range, Optional opt As Integer) As Long
getRGB4 = rcell.Interior.Color
Select Case opt
Case 1, 2, 3: getRGB4 = getRGB4 \ 256 ^ (opt - 1) Mod 256
End Select
End Function


2021-07-21 03:53:53

Philip

Willy, thanks a lot. I've been using Excel since version came out of the box, and now seeing that even a basic thing as the existence of this operator wasn't known to me ... shows how one never stops learning with this application :-)


2021-07-20 05:32:36

Willy Vanhaelen

@Philip
\ performs an integer division:

10 \ 3 = 3

5.2 \ 2 = 2

So the integer part of the division is returned and the decimals are dropped (there is no rounding).


2021-07-20 04:26:23

Philip

Chris, thanks. To my knowledge that would then have to be a forward slash (/ and not \), I haven't encountered "\" as an operator in a VBA statement yet, hence my question ...


2021-07-19 17:41:22

Chris

Philip - I'm guessing that's the division sign (\). C represents a number, so Willy is dividing C by 256 or 65536


2021-07-19 15:17:39

Philip

@Willy, what does the backslash in your expressions do ?


2021-07-17 10:58:44

Willy Vanhaelen

Here is a shorter version of the getRGB3 function in this tip:

Function getRGB3(rcell As Range, Optional opt As Integer) As Long
Dim C As Long
C = rcell.Interior.Color
Select Case opt
Case 1: getRGB3 = C Mod 256
Case 2: getRGB3 = C \ 256 Mod 256
Case 3: getRGB3 = C \ 65536 Mod 256
Case Else: getRGB3 = C
End Select
End Function


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.