Conditional Formated Cell Color and SUM issues

titoqan

New Member
Joined
Mar 10, 2016
Messages
18
Hello, first time poster but long time reader of this forum, it has been a great help!

Okay... I have a column of dates and have colored the rows by days of the week using conditional formating based on formula "=WEEKDAY($B9,1)=7" and applies to a range of "=$B$9:$BR$55"

Next I want to sum cells in a column range that have $BI$9:$BI$55 that have a cell colored based on the conditional formating formula assigned.

I found the following website Conditional Formatting Colors that seems like it should do what I am trying to accomplish. but I get a #NUM! result.

I am running excel2007, and have not done any real VBA coding.

VBA Code:
Code:
Function ActiveCondition(Rng As Range) As Integer
Dim Ndx As Long
Dim FC As FormatCondition
Dim Temp As Variant
Dim Temp2 As Variant
If Rng.FormatConditions.Count = 0 Then
    ActiveCondition = 0
Else
    For Ndx = 1 To Rng.FormatConditions.Count
        Set FC = Rng.FormatConditions(Ndx)
        Select Case FC.Type
            Case xlCellValue
            Select Case FC.Operator
                Case xlBetween
                    Temp = GetStrippedValue(FC.Formula1)
                    Temp2 = GetStrippedValue(FC.Formula2)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) >= CDbl(FC.Formula1) And _
                           CDbl(Rng.Value) <= CDbl(FC.Formula2) Then
                           ActiveCondition = Ndx
                           Exit Function
                       End If
                   Else
                      If Rng.Value >= Temp And _
                         Rng.Value <= Temp2 Then
                         ActiveCondition = Ndx
                         Exit Function
                      End If
                   End If
                Case xlGreater
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) > CDbl(FC.Formula1) Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    Else
                       If Rng.Value > Temp Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If
                Case xlEqual
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) = CDbl(FC.Formula1) Then
                           ActiveCondition = Ndx
                           Exit Function
                       End If
                    Else
                       If Temp = Rng.Value Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If

                Case xlGreaterEqual
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) >= CDbl(FC.Formula1) Then
                           ActiveCondition = Ndx
                           Exit Function
                       End If
                    Else
                       If Rng.Value >= Temp Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If
               
                Case xlLess
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                        If CDbl(Rng.Value) < CDbl(FC.Formula1) Then
                           ActiveCondition = Ndx
                           Exit Function
                        End If
                    Else
                        If Rng.Value < Temp Then
                           ActiveCondition = Ndx
                           Exit Function
                        End If
                    End If
                Case xlLessEqual
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) <= CDbl(FC.Formula1) Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    Else
                       If Rng.Value <= Temp Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If

                Case xlNotEqual
                    Temp = GetStrippedValue(FC.Formula1)
                    If IsNumeric(Temp) Then
                       If CDbl(Rng.Value) <> CDbl(FC.Formula1) Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    Else
                       If Temp <> Rng.Value Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If
               Case xlNotBetween
                    Temp = GetStrippedValue(FC.Formula1)
                    Temp2 = GetStrippedValue(FC.Formula2)
                    If IsNumeric(Temp) Then
                       If Not (CDbl(Rng.Value) <= CDbl(FC.Formula1)) And _
                          (CDbl(Rng.Value) >= CDbl(FC.Formula2)) Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    Else
                       If Not Rng.Value <= Temp And _
                          Rng.Value >= Temp2 Then
                          ActiveCondition = Ndx
                          Exit Function
                       End If
                    End If
             
               Case Else
                    Debug.Print "UNKNOWN OPERATOR"
           End Select

        Case xlExpression
            If Application.Evaluate(FC.Formula1) Then
               ActiveCondition = Ndx
               Exit Function
            End If
        Case Else
            Debug.Print "UNKNOWN TYPE"
       End Select
    Next Ndx
End If
ActiveCondition = 0
 
End Function
 
'''''''''''''''''''''''''''''''''''''''

Function ColorIndexOfCF(Rng As Range, _
    Optional OfText As Boolean = False) As Integer
Dim AC As Integer
AC = ActiveCondition(Rng)
If AC = 0 Then
    If OfText = True Then
       ColorIndexOfCF = Rng.Font.ColorIndex
    Else
       ColorIndexOfCF = Rng.Interior.ColorIndex
    End If
Else
    If OfText = True Then
       ColorIndexOfCF = Rng.FormatConditions(AC).Font.ColorIndex
    Else
       ColorIndexOfCF = Rng.FormatConditions(AC).Interior.ColorIndex
    End If
End If
End Function
 
'''''''''''''''''''''''''''''''''''''''

Function ColorOfCF(Rng As Range, Optional OfText As Boolean = False) As Long
Dim AC As Integer
AC = ActiveCondition(Rng)
If AC = 0 Then
    If OfText = True Then
       ColorOfCF = Rng.Font.Color
    Else
       ColorOfCF = Rng.Interior.Color
    End If
Else
    If OfText = True Then
       ColorOfCF = Rng.FormatConditions(AC).Font.Color
    Else
       ColorOfCF = Rng.FormatConditions(AC).Interior.Color
    End If
End If
End Function
'''''''''''''''''''''''''''''''''''''''
Function GetStrippedValue(CF As String) As String
    Dim Temp As String
    If InStr(1, CF, "=", vbTextCompare) Then
       Temp = Mid(CF, 3, Len(CF) - 3)
       If Left(Temp, 1) = "=" Then
           Temp = Mid(Temp, 2)
       End If
    Else
       Temp = CF
    End If
    GetStrippedValue = Temp
End Function
 
'''''''''''''''''''''''''''''''''''''''
Function CountOfCF(InRange As Range, _
    Optional Condition As Integer = -1) As Long
    Dim Count As Long
    Dim Rng As Range
    Dim FCNum As Integer
    For Each Rng In InRange.Cells
        FCNum = ActiveCondition(Rng)
        If FCNum > 0 Then
            If Condition = -1 Or Condition = FCNum Then
                Count = Count + 1
            End If
        End If
    Next Rng
    CountOfCF = Count
End Function
'''''''''''''''''''''''''''''''''''''''
Function SumByCFColorIndex(Rng As Range, CI As Integer) As Double
    Dim R As Range
    Dim Total As Double
    For Each R In Rng.Cells
        If ColorIndexOfCF(R, False) = CI Then
            Total = Total + R.Value
        End If
    Next R
    SumByCFColorIndex = Total
End Function

and In Cell BT10 I use this formula "=SumByCFColorIndex(BI9:BI55,$B$13)"

I should have deleted some of the functions as I am not using them, but this is what I copied and pasted into my file.

Thank you!
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
Welcome to the Forum!

SumByCFColorIndex expects an integer second argument:

Function SumByCFColorIndex(Rng As Range, CI As Integer) As Double

You're calling the function like this:

=SumByCFColorIndex(BI9:BI55,$B$13)

where, based on your question, $B$13 is a date?

The maximum integer is 32,767, i.e. 16 Sep 1989, hence the #NUM error if you try to pass a larger value.

But in any event, isn't CI meant to be the number of the format condition?
 
Upvote 0
why not just use SUMIFS() based on those same CF rules?

Something like...
=sumifS($BI$9:$BI$55 ,WEEKDAY($B9,1)=7,$B$9:$BR$55)
 
Upvote 0
Thank you for the quick reply :)

$B$13 is a date (April 5, 2016) which is above the max. I chose that cell because it is the correct cell color.

I changed the formula to" =SumByCFColorIndex(BI9:BI55,$BI$13)" where $BI$13 is the # of passengers on a bus during a shift on Sunday, and now cell"BT10" is empty. I know that I have passengers on Sunday.

I am trying to find out how many Sunday passengers we have had in a month on all Sunday shifts cell "BT10"
 
Upvote 0
I get a "formula you typed contains an error" when I paste "=sumifS($BI$9:$BI$55 ,WEEKDAY($B9,1)=7,$B$9:$BR$55)"
 
Upvote 0
I am trying =SUMPRODUCT

"=SUMPRODUCT((WEEKDAY(B9:B55,1)=1)*(BI9:BI55))"
Add all # in range BI9:BI55 that occur on Sunday
B9:B55 are dates and BI9:BI55 are # of passengers

I get a #VALUE! error

Any more sugestions?
 
Upvote 0
I think you're looking for:

=SUMPRODUCT(BI9:BI55,--(WEEKDAY(B9:B55,1)=7))
 
Upvote 0
I agree with Ford, by the way.

Rather than mess around with code to count conditionally formatted colours, just write a simple formula using the CF condition.
 
Upvote 0
Yeah, wasnt thinking too well on that. Try this instead...
G​
H​
I​
J​
1​
3/10/2016​
1​
50​
2​
3/13/2016​
2​
3​
3/16/2016​
3​
4​
3/19/2016​
4​
5​
3/22/2016​
5​
6​
3/25/2016​
6​
7​
3/28/2016​
7​
8​
3/31/2016​
8​
9​
4/3/2016​
9​
10​
4/6/2016​
10​
11​
4/9/2016​
11​
12​
4/12/2016​
12​
J1=SUMPRODUCT(--(WEEKDAY($G$1:$G$29,2)=7),($H$1:$H$29))
(I only copied to row 12, but you can see the pattern of my dates/data)
 
Upvote 0
That works cleanly and I don't even mess with any conditional formatting.

Questions what does "--" do in the formula?

Thanks a TON :D
 
Upvote 0

Forum statistics

Threads
1,214,590
Messages
6,120,423
Members
448,961
Latest member
nzskater

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