CountIFs with multiple criteria and duplication

sammipd

Board Regular
Joined
Jun 6, 2010
Messages
61
Within a larger spreadsheet I have a Type (alpha, beta) column and Code 1 and Code 2 columns. Code columns are numeric from 1.1-7.9. I need to determine the number of alpha's who are coded 5.0-5.9 in either column without duplication. Some alphas are coded 5.0-5.9 in both columns but should only be counted here once. There was a similar thread earlier today and I couldn’t tweak the responses to fit this problem. Can someone help?
 

sammipd

Board Regular
Joined
Jun 6, 2010
Messages
61
The question is how many Alpha's are coded in the 5.0-5.9 range. The answer should be 4 (lines 1,2,4,6).
Although lines 4 and 6 have 2 codes in the proper range, they should only be counted once. How can I make this work?

TypeCode1Code2
1Alpha5.73.2
2Alpha1.45.9
3Beta5.43.2
4Alpha5.35.8
5Beta6.85.2
6Alpha5.35.6
7Beta5.32.5
8Alpha3.46.5

<colgroup><col><col span="3"></colgroup><tbody>
</tbody>
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
8,996
If your Code 1 and Code 2 columns are adjacent, you can use the I2 formula. If not, the J2 formula should work.

ABCDEFGHIJ
1TypeCode 1Code 2TypeLower limitUpper LimitUnique Count
21Alpha5.73.2alpha55.944
32Alpha1.45.9
43Beta5.43.2
54Alpha5.35.8
65Beta6.85.2
76Alpha5.35.6
87Beta5.32.5
98Alpha3.46.5

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet16

Array Formulas
CellFormula
I2{=SUM(SIGN(MMULT(IF(($C$2:$D$9>=G2)*($C$2:$D$9<=H2)*($B$2:$B$9=F2),1,0),{1;1})))}
J2{=SUM(IF((($C$2:$C$9>=G2)*($C$2:$C$9<=H2)+($D$2:$D$9>=G2)*($D$2:$D$9<=H2))*($B$2:$B$9=F2),1))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>



Both are array formulas. Also, you can incorporate the F2:H2 values in the formula itself if you like.
 

Forum statistics

Threads
1,082,344
Messages
5,364,806
Members
400,814
Latest member
gangstar67

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top