Excel 2013 - VBA - Runtime Error 9 when creating & accessing [more than 4!] Conditional Formating Items - HELP PLEASE!

Mr Boris

New Member
Joined
Feb 25, 2015
Messages
10
Hi Excel VBA Gurus!

H.E.L.P. P.L.E.A.S.E

Am new here and hope someone can help, I am literally pulling my hair out. :confused:

I have searched and searched and not come up with a solution and cannot explain what is happening.

Basically I have a worksheet in Excel 2013 (on a Win 7 X86 machine) that has a worksheet with a selection of invoicing data on each row and many new rows are added each month. The worksheet has 8 conditional formats on it at various ranges which extend from the Top of the invoicing data to the bottom of the data .

As new rows of data get inserted [at the top of the range] in to the range using this approach:

Code:
Manager.Select
        Manager.Range("headerRow").Offset(1, 0).Range("a1:M1").Select
        Selection.Copy
        Selection.Insert Shift:=xlDown

<!-- end snippet -->the conditional formatting gets convoluted, messy, fragmented, duplicated for the specific new row and eventually after a few months is such a mess it seems stops working correctly.

After wasting several hours on various approaches my solution was to be "simple". (SURE!) When a row gets inserted at the top of the range then I want to clear and reset the 8 x conditional formats using VBA (- in essence perform a quick clean-up) by deleting all of the the conditional formatting on the worksheet and reapplying 8 clean conditional formats with the correct ranges and formatting for each of the ranges using the known Top and Bottom of the data range variables. With me so far?

The problem is that after adding and formatting 4 conditional formats using .FormatConditions.Add and .FormatConditions(x), Excel throws a Subscript Error when I attempt to format the CF Item 5 (or more) Font or background color. I have searched for an explanation and understand that basically I can add as many CF's as I like so what is going on?

The crazy thing is that it appeared to work correctly once then never again?

Here is my test code and it all works perfectly until formula 5, where it crashes. I have attempted to work around it but any CF index greater than 4 using .FormatConditions(x) crashes it.


Code:
Sub CFReset()

    ' Get top and bottom of Invoices
    TopRow = (Manager.Range("headerRow").Row) + 1
    BottomRow = ActiveSheet.UsedRange.Rows.Count

    ' Clear All Current Conditional Formatting on Manager Sheet between Invoice Top Row and Invoice Bottom Row
    Range("A" & TopRow & ":L" & BottomRow).FormatConditions.Delete

    'CD Formula 1 - 'Formula:  =AND(I17="Paid",G17<>0) - 'Colour: Red on White Background 'Applies to: =$G$17:$G$49
    With ActiveSheet.Range("$G$" & TopRow & ":$G$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Paid"",G" & TopRow & "<>0)"
        .FormatConditions(1).Font.ColorIndex = 3 ' Red
    End With

    'CD Formula 2 - '=AND(I17="Partial",F17<>0) 'Colour: Red on white background 'Applies to: =$G$17:$G$49
    With ActiveSheet.Range("$G$" & TopRow & ":$G$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Partial"",F" & TopRow & "<>0)"
        .FormatConditions(2).Font.ColorIndex = 3 ' Red
    End With

    'CD Formula 3 '=OR($I17="Void") - Text Colour RGB: 255,179,179 'Applies to: =$A$17:$I$49
    With ActiveSheet.Range("$A$" & TopRow & ":$I$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=OR($I" & TopRow & "=""Void"")"
        .FormatConditions(3).Font.Color = RGB(255, 179, 179) ' Pinkish
    End With

    'CD Formula 4 - '=OR($I17="Paid",$I17="Closed") - Text Colour: RGB 192, 192, 192 'Applies to: =$A$17:$I$49
    With ActiveSheet.Range("$A$" & TopRow & ":$I$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=OR($I" & TopRow & "=""Paid"",$I" & TopRow & "=""Closed"")"
        .FormatConditions(4).Font.Color = RGB(192, 192, 192) ' Gray
    End With

    'CD Formula 5 '=AND(I17="Paid",G17<>0) 'Color: RGB 0, 0, 0 'Black 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$F$17:$F$49
    With ActiveSheet.Range("$F$" & TopRow & ":$F$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Paid"",G" & TopRow & "<>0)"
        .FormatConditions(5).Font.ColorIndex = 1 ' Black
        .FormatConditions(5).Interior.Color = RGB(255, 255, 204) ' Light Yellow
    End With

    'CD Formula 6  '=AND(I17="Partial",F17=0) 'Color: RGB 0, 0, 0 'Black 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$F$17:$F$49
    With ActiveSheet.Range("$F$" & TopRow & ":$F$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Partial"",F" & TopRow & "=0)"
        .FormatConditions(6).Font.ColorIndex = 1 ' Black
        .FormatConditions(6).Interior.Color = RGB(255, 255, 204) ' Light Yellow
    End With


    'CD Formula 7 '=AND(G17>0,AND(D17<today(),d17<>"")) 'Colour: Red 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$D$17:$D$49
    With ActiveSheet.Range("$D$" & TopRow & ":$D$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(G" & TopRow & ">0,AND(D" & TopRow & "<today(),d" &="" toprow="" "<="">""""))"
        .FormatConditions(7).Font.ColorIndex = 3 ' Red
        .FormatConditions(7).Interior.Color = RGB(255, 255, 204) ' Light Yellow
    End With


    'CD Formula 8 '=COUNTIF($B:$B,B17)>1 'Color: RGB 255,255,255 -'White 'Background Colour: Red ' Rgb 255 ' Applies to: =$B$17:$B$49
    With ActiveSheet.Range("$B$" & TopRow & ":$B$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=COUNTIF($B:$B,B" & TopRow & ")>1"
        .FormatConditions(8).Font.ColorIndex = 2 ' White
        .FormatConditions(8).Interior.ColorIndex = 3 ' Red
    End With


    End Sub
<!-- end snippet -->


If I rem out the formatting of font and background the CF rule is added to the worksheet with formula and correct range but clearly without formatting this is a waste of time ! :eeek:

I also attempted a different way of formatting the font color and Background color however selecting a Conditional Formatting item with an index higher than 4 returns the same error.

Code:
'Attempt2
    With ActiveSheet.Range("$A$" & TopRow & ":$I$" & BottomRow).FormatConditions
        .Add Type:=xlExpression, Formula1:="=OR($I" & TopRow & "=""Void"")"
        With .Item(3).Font
            .Color = RGB(255, 179, 179) ' Pinkish
        End With
    End With
<!-- end snippet -->

I have included my remarks which are my notes for each of the formats - these are actually from my original CF's.

**Any assistance - guidance etc would be gratefully received. Feeling desperate**!

Seriously, I have wasted much time on this and cannot understand what the issue is. Why wont it let me add and format more than 4 items without an error and can I SOME HOW work around this problem.

Many thanks and kind regards in advance for any responses.

Mr Boris</today(),d"></today(),d17<>
 
Last edited:

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Here's a theory:
First you add two conditions to column G. Then you add a condition to columns A:L. That creates .FormatConditions(1) for columns A:F, H:L, and .FormatConditions(3) for column G. Perhaps (again this is just a theory), Excel is getting "confused" with the difference in conditions counts between the columns when you set the formatting. I vaguely remember a problem like this with an earlier version, but I don't recall the specifics.

You could set the .FormatConditions for columns G separately as it has a different conditions count. Or add the global multi-columns conditions first, and the column-specific conditions secondarily using .FormatConditions(.FormatConditions.Count). Also, once a condition is added, you could always change a condition's priority if needed.
 
Last edited:
Upvote 0
Thanks AlphaFrog for your super quick response and suggestions. Could you possibly clarify this:
"You could set the .FormatConditions for columns G separately as it has a different conditions count. Or add the global multi-columns conditions first, and the column-specific conditions secondarily using FormatConditions(.FormatConditions.Count). Also, once a condition is added, you could always change a condition's priority if needed. "

I'm not quite understanding what you mean? I thought that I had actually separated the CF's into 8 different conditions. Sorry to be a bit of a noob :(

Cheers
Mr Boris
 
Upvote 0
You do have 8 separate CFs, but if you are first adding two CFs to column G, those two Cfs are index 1 and 2. Then you are adding a CF to columns A:L. So columns A:F, H:L now have one CF with an index of 1, and Column G has that same CF with an index of 3.

So if you set the format for your 3rd CF using...
.FormatConditions(3).Font.Color = RGB(255, 179, 179) ' Pinkish
...columns A:F and columns H:L only have 1 CF with an index of 1. Does that make sense?

So I'm suggesting one possible solution is to 1st add the global CFs to columns A:L so each column has the same CF indexing. Then add the column specific CFs.

This adds the multi-column CFs first (Not tested)
Code:
[color=darkblue]Sub[/color] CFReset()
    
    [color=green]' Get top and bottom of Invoices[/color]
    TopRow = (Manager.Range("headerRow").Row) + 1
    BottomRow = ActiveSheet.UsedRange.Rows.Count
    
    [color=green]' Clear All Current Conditional Formatting on Manager Sheet between Invoice Top Row and Invoice Bottom Row[/color]
    Range("A" & TopRow & ":L" & BottomRow).FormatConditions.Delete
    
    [color=green]'CD Formula 3 '=OR($I17="Void") - Text Colour RGB: 255,179,179 'Applies to: =$A$17:$I$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$A$" & TopRow & ":$I$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=OR($I" & TopRow & "=""Void"")"
        .FormatConditions(.FormatConditions.Count).Font.Color = RGB(255, 179, 179) [color=green]' Pinkish[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 4 - '=OR($I17="Paid",$I17="Closed") - Text Colour: RGB 192, 192, 192 'Applies to: =$A$17:$I$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$A$" & TopRow & ":$I$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=OR($I" & TopRow & "=""Paid"",$I" & TopRow & "=""Closed"")"
        .FormatConditions(.FormatConditions.Count).Font.Color = RGB(192, 192, 192) [color=green]' Gray[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 1 - 'Formula:  =AND(I17="Paid",G17<>0) - 'Colour: Red on White Background 'Applies to: =$G$17:$G$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$G$" & TopRow & ":$G$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Paid"",G" & TopRow & "<>0)"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 3 [color=green]' Red[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 2 - '=AND(I17="Partial",F17<>0) 'Colour: Red on white background 'Applies to: =$G$17:$G$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$G$" & TopRow & ":$G$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Partial"",F" & TopRow & "<>0)"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 3 [color=green]' Red[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 5 '=AND(I17="Paid",G17<>0) 'Color: RGB 0, 0, 0 'Black 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$F$17:$F$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$F$" & TopRow & ":$F$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Paid"",G" & TopRow & "<>0)"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 1 [color=green]' Black[/color]
        .FormatConditions(.FormatConditions.Count).Interior.Color = RGB(255, 255, 204) [color=green]' Light Yellow[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 6  '=AND(I17="Partial",F17=0) 'Color: RGB 0, 0, 0 'Black 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$F$17:$F$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$F$" & TopRow & ":$F$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(I" & TopRow & "=""Partial"",F" & TopRow & "=0)"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 1 [color=green]' Black[/color]
        .FormatConditions(.FormatConditions.Count).Interior.Color = RGB(255, 255, 204) [color=green]' Light Yellow[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 7 '=AND(G17>0,AND(D17"")) 'Colour: Red 'Background Colour:RGB: 255,255,204 ' Light Yellow 'Applies to: =$D$17:$D$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$D$" & TopRow & ":$D$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=AND(G" & TopRow & ">0,AND(D" & TopRow & """""))"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 3 [color=green]' Red[/color]
        .FormatConditions(.FormatConditions.Count).Interior.Color = RGB(255, 255, 204) [color=green]' Light Yellow[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=green]'CD Formula 8 '=COUNTIF($B:$B,B17)>1 'Color: RGB 255,255,255 -'White 'Background Colour: Red ' Rgb 255 ' Applies to: =$B$17:$B$49[/color]
    [color=darkblue]With[/color] ActiveSheet.Range("$B$" & TopRow & ":$B$" & BottomRow)
        .FormatConditions.Add Type:=xlExpression, Formula1:="=COUNTIF($B:$B,B" & TopRow & ")>1"
        .FormatConditions(.FormatConditions.Count).Font.ColorIndex = 2 [color=green]' White[/color]
        .FormatConditions(.FormatConditions.Count).Interior.ColorIndex = 3 [color=green]' Red[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
[color=darkblue]End[/color] [color=darkblue]Sub[/color]
 
Last edited:
Upvote 0
AlphaFrog.... WOW This works 100%. :rofl:

I was scratching my head for a few hours on this frustrating problem and you took a look and smashed in first time! Awesome!

I am totally grateful for your time and effort to
A) Review my issue
B) Patiently explain my error and
C) Show me the right path!

Rearranging the order and using .FormatConditions.Count has truly been a game changer!

Thank you again!

Mr Boris
 
Upvote 0
You're welcome and thanks for the feedback.

On a side note; The OR function in this CF formula is superfluous.
Formula1:="=OR($I" & TopRow & "=""Void"")"
 
Upvote 0
You're welcome and thanks for the feedback.

On a side note; The OR function in this CF formula is superfluous.
Formula1:="=OR($I" & TopRow & "=""Void"")"

Thanks AlphaFrog but I' might have to disagree on that one lol. :)

When that cell contents in Column I-Row(xx) is changed (using a drop-down) to "Void" the row A(xx)-I(xx) needs to be changed to light pink text on a white background indicating that the invoice & transaction has been voided. Without Formula1:="=OR($I" & TopRow & "=""Void"")" this condition is not set. Am I missing something? :eeek::biggrin:

All good! :)

Cheers again for you amazing support

Regards
Mr Boris
 
Upvote 0
Thanks AlphaFrog but I' might have to disagree on that one lol. :)

When that cell contents in Column I-Row(xx) is changed (using a drop-down) to "Void" the row A(xx)-I(xx) needs to be changed to light pink text on a white background indicating that the invoice & transaction has been voided. Without Formula1:="=OR($I" & TopRow & "=""Void"")" this condition is not set. Am I missing something? :eeek::biggrin:

All good! :)

Cheers again for you amazing support

Regards
Mr Boris

Did you try it?
Formula1:="=$I" & TopRow & "=""Void"""
This returns TRUE or FALSE without the OR function.

The OR function needs two or more boolean values to compare. The I-Row(xx)="Void" returns one boolean (True or False). So if you OR one Boolean, it returns the same value.
OR(TRUE) returns True
OR(FALSE) returns False
So that makes it superfluous.
 
Upvote 0
Obi Wan AlphaFrog... :) you are of course correct :cool:-

However strangely when I use the =OR, or =AND it does work 100% too even though logic would perhaps dictate not.

Removing the operator and just having: Formula1:="=$I" & TopRow & "=""Void""" is the way to go and I have tweaked it :)

Cheers again - appreciate the feedback!

Mr Boris
(Your very happy customer)
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,917
Members
452,366
Latest member
TePunaBloke

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