Sumproduct help

Joneye

Well-known Member
Joined
May 28, 2010
Messages
785
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
  2. MacOS
Brain stopped again, I know my answer is 6 im sure im close to the answer here, any help would be appreciated.

<b>Excel 2003</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Item Status</td><td style=";">Add Date</td><td style=";">Status Date</td><td style=";">Access Count</td><td style=";">Destroy Date</td><td style=";">Object Code</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">In</td><td style="text-align: right;;">02/03/2005</td><td style="text-align: right;;">03/03/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA-EXL</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style=";">out</td><td style="text-align: right;;">14/04/2005</td><td style="text-align: right;;">15/04/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style=";">TEST</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style=";">In</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style=";">In</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style=";">In</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style=";">In</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style=";">In</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">30/08/2005</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td><td style=";">DATA</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C1</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">A3:A15="In"</font>),--(<font color="Red">A3:A15="Out"</font>),--(<font color="Red">F3:F15="Data"</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 
Last edited:

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
Well, a single cell cannot equal BOTH In AND Out..

Are you trying to get if a cell = In OR Out?

Try
=SUMPRODUCT(--((A3:A113="In")+(A3:A113="Out")>0),--(F3:F113="Data"))
 
Upvote 0
Try this regular formula:
Code:
C1: =SUMPRODUCT((A3:A113={"In","Out"})*(F3:F113="Data"))
Does that help?
 
Upvote 0
Brain stopped again, I know my answer is 6 im sure im close to the answer here, any help would be appreciated.

Excel 2003<TABLE style="BORDER-RIGHT: #a6aab6 1px solid; BORDER-TOP: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BORDER-BOTTOM: #a6aab6 1px solid; BORDER-COLLAPSE: collapse; BACKGROUND-COLOR: #ffffff" cellPadding=2 rules=all><COLGROUP><COL style="BACKGROUND-COLOR: #e0e0f0" width=25><COL><COL><COL><COL><COL><COL></COLGROUP><THEAD><TR style="COLOR: #161120; BACKGROUND-COLOR: #e0e0f0; TEXT-ALIGN: center"><TH></TH><TH>A</TH><TH>B</TH><TH>C</TH><TH>D</TH><TH>E</TH><TH>F</TH></TR></THEAD><TBODY><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: right"></TD><TD style="TEXT-ALIGN: right"></TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD style="TEXT-ALIGN: right"></TD><TD style="TEXT-ALIGN: right"></TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">2</TD><TD>Item Status</TD><TD>Add Date</TD><TD>Status Date</TD><TD>Access Count</TD><TD>Destroy Date</TD><TD>Object Code</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">3</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">4</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">5</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">6</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">7</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">8</TD><TD>In</TD><TD style="TEXT-ALIGN: right">02/03/2005</TD><TD style="TEXT-ALIGN: right">03/03/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA-EXL</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">9</TD><TD>out</TD><TD style="TEXT-ALIGN: right">14/04/2005</TD><TD style="TEXT-ALIGN: right">15/04/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">10</TD><TD>TEST</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">11</TD><TD>In</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">12</TD><TD>In</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">13</TD><TD>In</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">14</TD><TD>In</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR><TR><TD style="COLOR: #161120; TEXT-ALIGN: center">15</TD><TD>In</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">30/08/2005</TD><TD style="TEXT-ALIGN: right">0</TD><TD style="TEXT-ALIGN: right"></TD><TD>DATA</TD></TR></TBODY></TABLE>
Sheet1


<TABLE style="BORDER-RIGHT: black 2px solid; PADDING-RIGHT: 0.4em; BORDER-TOP: black 2px solid; PADDING-LEFT: 0.4em; PADDING-BOTTOM: 0.4em; BORDER-LEFT: black 2px solid; PADDING-TOP: 0.4em; BORDER-BOTTOM: black 2px solid; BORDER-COLLAPSE: collapse; BACKGROUND-COLOR: #ffffff" cellPadding=2 rules=all width="85%"><TBODY><TR><TD style="PADDING-RIGHT: 6px; PADDING-LEFT: 6px; PADDING-BOTTOM: 6px; PADDING-TOP: 6px">Worksheet Formulas<TABLE style="BORDER-RIGHT: #a6aab6 1px solid; BORDER-TOP: #a6aab6 1px solid; BORDER-LEFT: #a6aab6 1px solid; BORDER-BOTTOM: #a6aab6 1px solid; BORDER-COLLAPSE: collapse; BACKGROUND-COLOR: #ffffff; TEXT-ALIGN: center" cellPadding=2 rules=all width="100%"><THEAD><TR style="COLOR: #161120; BACKGROUND-COLOR: #e0e0f0"><TH width=10>Cell</TH><TH style="PADDING-LEFT: 5px; TEXT-ALIGN: left">Formula</TH></TR></THEAD><TBODY><TR><TH style="COLOR: #161120; BACKGROUND-COLOR: #e0e0f0" width=10>C1</TH><TD style="TEXT-ALIGN: left">=SUMPRODUCT(--(A3:A15="In"),--(A3:A15="Out"),--(F3:F15="Data"))</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>
Here's another one...

=SUMPRODUCT(--(ISNUMBER(MATCH(A3:A15,{"In","Out"}))),--(F3:F15="Data"))

Better to use cells to hold the criteria:
  • H3 = In
  • H4 = Out
  • H5 = Data
=SUMPRODUCT(--(ISNUMBER(MATCH(A3:A15,H3:H4))),--(F3:F15=H5))
 
Upvote 0
Or...
with
H3: In
H4: Out
H5: Data
...something like this regular formula
Code:
C1: =SUMPRODUCT(COUNTIF(H3:H4,A3:A113)*(F3:F113=H5)

For the comma-separator mavens:
Code:
=SUMPRODUCT(COUNTIF(H3:H4,A3:A113),--(F3:F113=H5))
 
Upvote 0
GUYS MANY THANKS im going to try them all and find a suiter
 
Upvote 0

Forum statistics

Threads
1,224,600
Messages
6,179,834
Members
452,947
Latest member
Gerry_F

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