CALCULATING COLOUR

mrbeanyuk

Board Regular
Joined
Nov 30, 2005
Messages
213
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!
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
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
 
Upvote 0
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
 
Upvote 0
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!
 
Upvote 0
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
 
Upvote 0

Forum statistics

Threads
1,214,567
Messages
6,120,268
Members
448,953
Latest member
Dutchie_1

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top