sumproduct formula excluding values from separate column

Bornready

New Member
Joined
Apr 25, 2022
Messages
2
Office Version
  1. 2021
  2. 2019
Platform
  1. Windows
how do i create a formula that still uses sumproduct but excludes data if it contains a text in a separate column?

ex: looking for data that fits the criteria apples, oranges, grapes, bananas, but in a separate column, if it's the color yellow for any of my criteria's then i want to exclude its total.

hopefully this makes sense.
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
Please try this.

Book1
ABC
1AppleGreen2
2BananaBlue
3KiwiYellow
4OrangeBeige
5PeachBrown
6PearRed
7PineapplePink
8PlumPurple
9TomatoOrange
10WatermelonTan
Sheet1
Cell Formulas
RangeFormula
C1C1=SUMPRODUCT((($A$1:$A$10="pear")+($A$1:$A$10="tomato")+($A$1:$A$10="kiwi")),--($B$1:$B$10<>"yellow"))
 
Upvote 0
Question what is the purpose of the --?
The "--" coerces the resulting TRUE/FALSE values in the formula into their corresponding values 1/0. Actually any math operation will do that. You will frequently see people add a 0 or multiply by 1. The "--" is called a double unary. It reportedly calculates fastest of all the methods (though I have never tested this).

Note the $B$1:$B$10< should be $B$1:$B$10<> for "does not equal"
 
Upvote 0

Forum statistics

Threads
1,215,727
Messages
6,126,521
Members
449,316
Latest member
sravya

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