Modify a Formula to Include an OR statement

SanFelippo

Board Regular
Joined
Apr 4, 2017
Messages
124
Hey All,
I thought this was an easy tweak, but apparently not so, atleast for me. Must have something to do with how excel is dealing with thearray formula, so hopefully someone else has a better understanding.
This is my current formula:
{=SUM(IF(FREQUENCY(IF(Jan!$N:$N="ValidError",Jan!$D:$D),Jan!$D:$D),1))}

I am trying to make this tweak:
{=SUM(IF(FREQUENCY(IF(OR(Jan!$N:$N="ValidError", Jan!$N:$N=“CBB Identified Error”),Jan!$D:$D),Jan!$D:$D),1))}.

So essentially I want it to count if column N containseither of this two phrases. I am getting a #NAME? Error.
Any ideas?
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Try
=SUM(IF(FREQUENCY((IF(Jan!$N:$N="ValidError",Jan!$D:$D))+(IF(Jan!$N:$N="CBB Identified Error",Jan!$D:$D)),Jan!$D:$D),1))

You are getting the #Name ? error as the quotes are wrong, they should be "
 
Upvote 0
Sorry for the late reply. This doesn't appear to be working. The original formula, which was {=SUM(IF(FREQUENCY(IF(Jan!$N:$N="Valid Error",Jan!$D:$D),Jan!$D:$D),1))}, gives me a count of 35. The new formula you gave me is only giving me a count of 1.

Since I want to be in a sense adding an OR statement to look for either "Valid Error" or "CBB Identified Error", if anything the count should go up.
 
Upvote 0
Can you post some sample data?
Also with array formulae you should avoid using whole columns.
 
Upvote 0
Hi, here is an alternative you could try.

=SUM(IF(FREQUENCY(IF(ISNUMBER(MATCH(Jan!$N1:$N100,{"Valid Error","CBB Identified Error"},0)),Jan!$D1:$D100),Jan!$D1:$D100),1))

Extend the end rows to sensible maximums or consider using dynamic named ranges or tables along with structured references.
 
Upvote 0
Sample Data is below. To give you an idea of how it works. This is original formula I had in there:



{=SUM(IF(FREQUENCY(IF(Jan!$N:$N="Valid Error",Jan!$D:$D),Jan!$D:$D),1))}


this formula for the sample data below gives me a count of 9, as there are 9 unique Loans that had a "Valid Error." I set up the formula this way because there are duplicate Loan Numbers. It also has to reference the whole column because I never know how many rows of data will be dropped in.


The new formula I am trying to come up with would give me a final count of 12, as there are 12 unique applications that had either a "Valid Error" or a "CBB Identified Error."


Loan NumberCCS Response
6Valid Error
6Valid Error
7CBB Identified Error
7CBB Identified Error
8OK
9OK
10OK
15Observation
16CBB Identified Error
17OK
18Valid Error
18Valid Error
28OK
28Valid Error
34Valid Error
35OK
38Observation
39Valid Error
40Valid Error
40Valid Error
40Valid Error
44OK
47Valid Error
48OK
52CBB Identified Error
56OK
57OK
58OK
25OK
1Valid Error
1CBB Identified Error
1CBB Identified Error
1CBB Identified Error
1Valid Error
1Valid Error
2Valid Error
2Valid Error
2Valid Error

<colgroup><col width="159" style="width: 119pt; mso-width-source: userset; mso-width-alt: 5814;"><colgroup><col width="131" style="width: 98pt; mso-width-source: userset; mso-width-alt: 4790;"><tbody>
</tbody>
 
Upvote 0
Have you tried FormR's suggestion in post#5, it works for me.
 
Upvote 0
The code in Post#5 works just fine. I can definitely work in dynamic named ranges to account for the changing number of rows

Thank you both!
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,751
Members
448,989
Latest member
mariah3

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