ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   How do I test values in 2 different columns in a "sumif" formula? (https://www.excelbanter.com/excel-discussion-misc-queries/144981-how-do-i-test-values-2-different-columns-sumif-formula.html)

SteveS

How do I test values in 2 different columns in a "sumif" formula?
 
I want to sum values in column C based on a test of text values in columns A
& B. Sumif only seems to support testing the value of one column not two.
Is there a way to accomplish my goal?





Roger Govier

How do I test values in 2 different columns in a "sumif" formula?
 
Hi Steve

=SUMPRODUCT(($A$1:$A$100="text1")*($B$1:$B$100="te xt2")*$C$1:$C$100)

Change ranges to suit, but ensure that they are of equal size.
--
Regards

Roger Govier


"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in
columns A
& B. Sumif only seems to support testing the value of one column not
two.
Is there a way to accomplish my goal?







Bob Phillips

How do I test values in 2 different columns in a "sumif" formula?
 
=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in columns
A
& B. Sumif only seems to support testing the value of one column not two.
Is there a way to accomplish my goal?







T. Valko

How do I test values in 2 different columns in a "sumif" formula?
 
Try something like this:

=SUMPRODUCT(--(A1:A10="some_text"),--(B1:B10="some_text"),C1:C10)

Better to use cells to hold the criteria:

E1 = whatever
E2 = whatever

=SUMPRODUCT(--(A1:A10=E1),--(B1:B10=E2),C1:C10)

Biff

"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in columns
A
& B. Sumif only seems to support testing the value of one column not two.
Is there a way to accomplish my goal?







ShaneDevenshire

How do I test values in 2 different columns in a "sumif" formu
 
Hi,

What is the advantage of this over Roger's formula?

--
Thanks,
Shane Devenshire


"Bob Phillips" wrote:

=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in columns
A
& B. Sumif only seems to support testing the value of one column not two.
Is there a way to accomplish my goal?








T. Valko

How do I test values in 2 different columns in a "sumif" formu
 
Slightly more efficient.

If you have Excel 2002 or higher use the Evaluate Formula command and see
how many steps it takes each variation of the formula to calculate. I would
use a small data set for this, like 5-10 rows.

If you actually timed the calculation the difference would probably be
negligible on a small dataset. But on a large dataset there is a
considerable difference.

Screecap:

average calc times for 10 rows and 10,000 rows

http://img46.imageshack.us/img46/4064/calctimesax7.jpg

Biff

"ShaneDevenshire" wrote in
message ...
Hi,

What is the advantage of this over Roger's formula?

--
Thanks,
Shane Devenshire


"Bob Phillips" wrote:

=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific
ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my
addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in
columns
A
& B. Sumif only seems to support testing the value of one column not
two.
Is there a way to accomplish my goal?










Dave Peterson

How do I test values in 2 different columns in a "sumif" formu
 
Bob has some details--when one formula is better than the other (and under
different circumstances, each will be better than the other):

http://www.xldynamic.com/source/xld.SUMPRODUCT.html



ShaneDevenshire wrote:

Hi,

What is the advantage of this over Roger's formula?

--
Thanks,
Shane Devenshire

"Bob Phillips" wrote:

=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in columns
A
& B. Sumif only seems to support testing the value of one column not two.
Is there a way to accomplish my goal?








--

Dave Peterson

ShaneDevenshire

How do I test values in 2 different columns in a "sumif" formu
 
Ah! so it's a speed issue, I hadn't tested that.
--
Thanks,
Shane Devenshire


"T. Valko" wrote:

Slightly more efficient.

If you have Excel 2002 or higher use the Evaluate Formula command and see
how many steps it takes each variation of the formula to calculate. I would
use a small data set for this, like 5-10 rows.

If you actually timed the calculation the difference would probably be
negligible on a small dataset. But on a large dataset there is a
considerable difference.

Screecap:

average calc times for 10 rows and 10,000 rows

http://img46.imageshack.us/img46/4064/calctimesax7.jpg

Biff

"ShaneDevenshire" wrote in
message ...
Hi,

What is the advantage of this over Roger's formula?

--
Thanks,
Shane Devenshire


"Bob Phillips" wrote:

=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific
ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my
addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in
columns
A
& B. Sumif only seems to support testing the value of one column not
two.
Is there a way to accomplish my goal?











Bob Phillips

How do I test values in 2 different columns in a "sumif" formu
 
It's also an aesthetic thing, it looks 'righter' to me, although there are
instances where one works and the other doesn't and vice versa.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my addy)



"ShaneDevenshire" wrote in
message ...
Ah! so it's a speed issue, I hadn't tested that.
--
Thanks,
Shane Devenshire


"T. Valko" wrote:

Slightly more efficient.

If you have Excel 2002 or higher use the Evaluate Formula command and see
how many steps it takes each variation of the formula to calculate. I
would
use a small data set for this, like 5-10 rows.

If you actually timed the calculation the difference would probably be
negligible on a small dataset. But on a large dataset there is a
considerable difference.

Screecap:

average calc times for 10 rows and 10,000 rows

http://img46.imageshack.us/img46/4064/calctimesax7.jpg

Biff

"ShaneDevenshire" wrote in
message ...
Hi,

What is the advantage of this over Roger's formula?

--
Thanks,
Shane Devenshire


"Bob Phillips" wrote:

=SUMPRODUCT(--(A2:A200="value1"),--(B2:B200="value2),C2:C200)

SP doesn't support full columns (not until Excel 200&), but specific
ranges.

--
---
HTH

Bob

(there's no email, no snail mail, but somewhere should be gmail in my
addy)



"SteveS" wrote in message
...
I want to sum values in column C based on a test of text values in
columns
A
& B. Sumif only seems to support testing the value of one column
not
two.
Is there a way to accomplish my goal?














All times are GMT +1. The time now is 03:48 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com