CountIFs with multiple criteria and duplication

sammipd

Board Regular
Joined
Jun 6, 2010
Messages
69
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?
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
A small data sample (~10 rows) along with expected result(s) would be helpful.

M.
 
Upvote 0
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?

[TABLE="width: 222"]
<colgroup><col><col span="3"></colgroup><tbody>[TR]
[TD][/TD]
[TD]Type[/TD]
[TD]Code1[/TD]
[TD]Code2[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]Alpha[/TD]
[TD]5.7[/TD]
[TD]3.2[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Alpha[/TD]
[TD]1.4[/TD]
[TD]5.9[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]Beta[/TD]
[TD]5.4[/TD]
[TD]3.2[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]Alpha[/TD]
[TD]5.3[/TD]
[TD]5.8[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]Beta[/TD]
[TD]6.8[/TD]
[TD]5.2[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]Alpha[/TD]
[TD]5.3[/TD]
[TD]5.6[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]Beta[/TD]
[TD]5.3[/TD]
[TD]2.5[/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]Alpha[/TD]
[TD]3.4[/TD]
[TD]6.5[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
If your Code 1 and Code 2 columns are adjacent, you can use the I2 formula. If not, the J2 formula should work.

ABCDEFGHIJ
TypeCode 1Code 2TypeLower limitUpper LimitUnique Count
alpha

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]
[TD="align: right"][/TD]

[TD="align: right"][/TD]

[TD="align: right"][/TD]

[TD="align: center"]2[/TD]
[TD="bgcolor: #FAFAFA, align: right"]1[/TD]
[TD="bgcolor: #FAFAFA"]Alpha[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.7[/TD]
[TD="bgcolor: #FAFAFA, align: right"]3.2[/TD]
[TD="align: right"][/TD]

[TD="align: right"]5[/TD]
[TD="align: right"]5.9[/TD]
[TD="align: right"]4[/TD]
[TD="align: right"]4[/TD]

[TD="align: center"]3[/TD]
[TD="bgcolor: #FAFAFA, align: right"]2[/TD]
[TD="bgcolor: #FAFAFA"]Alpha[/TD]
[TD="bgcolor: #FAFAFA, align: right"]1.4[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.9[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]4[/TD]
[TD="bgcolor: #FAFAFA, align: right"]3[/TD]
[TD="bgcolor: #FAFAFA"]Beta[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.4[/TD]
[TD="bgcolor: #FAFAFA, align: right"]3.2[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]5[/TD]
[TD="bgcolor: #FAFAFA, align: right"]4[/TD]
[TD="bgcolor: #FAFAFA"]Alpha[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.3[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.8[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]6[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5[/TD]
[TD="bgcolor: #FAFAFA"]Beta[/TD]
[TD="bgcolor: #FAFAFA, align: right"]6.8[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.2[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]7[/TD]
[TD="bgcolor: #FAFAFA, align: right"]6[/TD]
[TD="bgcolor: #FAFAFA"]Alpha[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.3[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.6[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]8[/TD]
[TD="bgcolor: #FAFAFA, align: right"]7[/TD]
[TD="bgcolor: #FAFAFA"]Beta[/TD]
[TD="bgcolor: #FAFAFA, align: right"]5.3[/TD]
[TD="bgcolor: #FAFAFA, align: right"]2.5[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]9[/TD]
[TD="bgcolor: #FAFAFA, align: right"]8[/TD]
[TD="bgcolor: #FAFAFA"]Alpha[/TD]
[TD="bgcolor: #FAFAFA, align: right"]3.4[/TD]
[TD="bgcolor: #FAFAFA, align: right"]6.5[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

</tbody>
Sheet16

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Array Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: #DAE7F5"]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: #DAE7F5"]I2[/TH]
[TD="align: left"]{=SUM(SIGN(MMULT(IF(($C$2:$D$9>=G2)*($C$2:$D$9<=H2)*($B$2:$B$9=F2),1,0),{1;1})))}[/TD]
[/TR]
[TR]
[TH="width: 10px, bgcolor: #DAE7F5"]J2[/TH]
[TD="align: left"]{=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))}[/TD]
[/TR]
</tbody>[/TABLE]
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself[/TD]
[/TR]
</tbody>[/TABLE]



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

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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