CALCULATING COLOUR

mrbeanyuk

Board Regular
Joined
Nov 30, 2005
Messages
212
Right, an interesting one for you guys.....

I have a spreadsheet with many different colours relating to various subjects. I am looking for a formula that will count the number of one colour in a particular column. Is this achieveable?

NB: The colours are manually input and not conditionally formatted.

Thanks!
 

Some videos you may like

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.

DominicB

Well-known Member
Joined
Oct 3, 2005
Messages
1,569
Good morning mrbeanyuk

Two choices : if you're farily well up on mcaros, have a look here for some custom written functions to add to your spreadsheet :

http://www.cpearson.com/excel/colors.htm

Alternatively, download my add-in via the link below. Once installed this will add a number of new functions to your Excel environment, five of which would be :

=FontColour(A1)
=CellColour(A1)
=SumFontCol(A1:A100,5)
=SumCellCol(A1:A100,10)
=CountFontCol(A1:A100,5)
=CountCellCol(A1:A100,10)

HTH

DominicB
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Hi MrBeanyUK

The following is a fairly trivial UDF that uses three arguments (a cell coloured with the colour you want to count, the range from which to count relevantly coloured cells, and an optional third argument which, if left blank, will count the cells, or if any other value than 1 is entered, will sum the relevant cells):

Code:
Function ColourCells(RefCell As Range, TargetCells As Range, Optional SumOrCount As Integer = 1) As Double
Dim iColIndex As Integer, c As Range, temp As Double
iColIndex = RefCell.Interior.ColorIndex
temp = 0
For Each c In TargetCells
    If SumOrCount = 1 Then
        If c.Interior.ColorIndex = iColIndex Then temp = temp + 1
    Else
        If c.Interior.ColorIndex = iColIndex Then temp = temp + c.Value
    End If
Next c
ColourCells = temp
End Function

So, if you had a range in A1:A20 and you wanted to count the red cells, you could use the formula thus:

Code:
=ColourCells(B1,A1:A20)

which assumes you have coloured B1 red also (from the toolbar).

Hope this helps!

Richard
 

mrbeanyuk

Board Regular
Joined
Nov 30, 2005
Messages
212
Many thanks for your help guys, however I am not very upto it with VB and I am restricted on the work PC to downloading add-ins.

With the VB coding, would you mind writing it for me please!?!?!?!

I want C,2 of 'sheet2' to count the number of yellow cells in column C of the 'sheet1'

Sorry and thanks!
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707

ADVERTISEMENT

Copy the code I posted from "Function Colour Cells.... End Function" and in your spreadsheet go Tools>Macro>Visual Basic Editor which will open up a new window. In the top left of the new window you should be able to see your workbook's name listed there. Right-click on it and go Insert>Module and paste the function code in there. Once you've done that, you can close the VBE down. Back in your spreadsheet, on Sheet2, select a cell and colour it yellow using the toolbar button (ie so this will be the same colour you want to count) - say this is C1. Then, in C2 enter:

Code:
=ColourCells(C1,Sheet1!C:C)

Richard
 

Watch MrExcel Video

Forum statistics

Threads
1,114,384
Messages
5,547,634
Members
410,804
Latest member
bluepinky
Top