Eng-Tips is the largest engineering community on the Internet

Intelligent Work Forums for Engineering Professionals

  • Congratulations waross on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

countif with booleans?

Status
Not open for further replies.

ACtrafficengr

Civil/Environmental
Jan 5, 2002
1,641
0
0
US
This is what I want to do:

Countif[(column a=1) AND {(10<column b<30) OR (column c = 7 OR 8)}]

For example, given
A B C
1 12
2 5
1 1 8
1 1 5
4
1 28

it would return "3."

Any advise on how to code this?


"...students of traffic are beginning to realize the false economy of mechanically controlled traffic, and hand work by trained officers will again prevail." - Wm. Phelps Eno, ca. 1928

"I'm searching for the questions, so my answers will make sense." - Stephen Brust

 
Replies continue below

Recommended for you

You need a "helper" column. Countif can only have one very simple condition. Use Column D and put in a formula to return "T" or "F" (or whatever you like). Then use CountIf on the helper column.

-handleman, CSWP (The new, easy test)
 
You should try with this function
=SUM(1*(A2:A7=1))+SUM((1*(B2:B7>10)*(B2:B7<30)))+SUM(1*(C2:C7=7))+SUM(1*(C2:C7=8))

remember to press CTRL+ALT+ENTER instead of ENTER when you digit the formula
(assuming that your numbers are in A2:C7)
Stefano
 
You can also use DCOUNT or DCOUNTA.

If your data is in A2:C7, with a header row A B C, for example, you can set up a criteria range, say in G1:J4 that looks like this:[tt]
A B B C
1 >10 <30
1 7
1 8
[/tt]
The criteria on the same line have to apply all (AND), on different lines represent OR.
The counting formula will look like this:[tt]
=DCOUNTA(A1:C7,"A",G1:J4)
[/tt]

Note that the ranges specified include the column labels, because they are used as field identifiers in the "database."

Cheers,
Joerd

Please see FAQ731-376 for tips on how to make the best use of Eng-Tips.
 
I believe this formula will do what you want:
=SUMPRODUCT((A2:A7=1)*(SIGN((B2:B7>10)*(B2:B7<30)+(C2:C7=7)+(C2:C7=8))))
and it does NOT need to be entered as an array formula (although it will still work correctly if it is).

The approach underlying this formula is discussed at URL
I was put onto this site by some post in this forum (if I recall correctly).

The URL concentrates on conditions that need to be satisfied simultaneously (ie AND operations). I developed the use of the SIGN function to extend the approach to include conditions that only need to be satisfied alternatively (ie OR operations).

Onda. I do not think your formula correctly implements the logic ACtrafficengr wanted. When I evaluate your formula on his data it returns 7, not 3.
 
Denial. You right, I misunderstanding the ACtraffincengr formula.
the way my formula should work is:
=SUM((A2:A7=1)*(((B2:B7>10)*(B2:B7<30)+(C2:C7=7)+(C2:C7=8))>=1))
Is an array formula, so press Shift+Ctrl+Enter

Regards
Onda
 
Status
Not open for further replies.
Back
Top