Formula Question

roadrunner

New Member
Joined
Mar 30, 2002
Messages
1
What is the formula for wanting to get the TOTAL number of cells with the word "SGT" in the range A1:A50, BUT ONLY count them IF the word "GO" appears in the range B1:B50? I can get them separatly but not together. Please help.
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
try the following

=sum((a1:a65336="sgt"(*(b1:b65336="go"))

Press Ctrl+shift+enter to make the formula work.........
 
Upvote 0
On 2002-03-31 17:52, kinkyparamour wrote:
try the following

=sum((a1:a65336="sgt"(*(b1:b65336="go"))

Press Ctrl+shift+enter to make the formula work.........

I think that should be

=sum((a1:a65336="sgt")*(b1:b65336="go"))


:)
 
Upvote 0
Also, you may want to trim down those ranges in the formula to your actual A1:A50 - you'll notice the performance difference when you recalc.

If your real data is, in fact, thousands of rows though, I'd suggest you take a look at Excel's database functions : =DCOUNT in particular.

A couple of extra options :)
 
Upvote 0
On 2002-04-01 02:59, Chris Davison wrote:
Also, you may want to trim down those ranges in the formula to your actual A1:A50 - you'll notice the performance difference when you recalc.

If your real data is, in fact, thousands of rows though, I'd suggest you take a look at Excel's database functions : =DCOUNT in particular.

A couple of extra options /board/images/smiles/icon_smile.gif

Chris,

You amaze me. You need to make a distinction between a single cell array or SUMPRODUCT formula and one that gets copied down to a huge number of cells.

Lets take the Roadrunner case.

=SUM((A1:A50="SGT")*(B1:B50="GO"))

array-entered, or

=SUMPRODUCT((A1:A50="SGT")*(B1:B50="GO"))

normally entered will not differ much in performance cost compared with DCOUNTA, not DCOUNT.

In order to apply DCOUNTA, you must have labels in A and B, say, Field1 and Field2.

You'll need to enter the following in an area, say, C1:D2.

{"Field1","Field2";
"SGT","GO"}

Now, you can use:

=DCOUNTA(A1:B50,1,C1:D2)

Aladin
 
Upvote 0

Forum statistics

Threads
1,213,531
Messages
6,114,172
Members
448,554
Latest member
Gleisner2

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