Sum of a column (w/out duplicates) based on 3 conditions

Estimator_J

New Member
Joined
Nov 23, 2016
Messages
4
Hello,

I have one column where the "State" is listed.
Another column states "Public" or "Private".
I would like to sum the "Amount" column for each state based on public or private.
However, there are duplicates in the amount column so I need the result to not include duplicates.

I have another formula for figuring out the amount based on state only but I would like to take it a step further and add another condition, public or private. Does anyone have an idea of how to structure the formula for the third condition?

Thank you!
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)

jorismoerings

Well-known Member
Joined
Jul 4, 2014
Messages
1,284
Hi,

Take a look at this and see if this will help:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">state</td><td style=";">status</td><td style=";">amount</td><td style="text-align: right;;"></td><td style=";">Florida</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Florida</td><td style=";">Public</td><td style="text-align: right;;">100</td><td style="text-align: right;;"></td><td style=";">Public</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Florida</td><td style=";">Private</td><td style="text-align: right;;">200</td><td style="text-align: right;;"></td><td style="text-align: right;;">201</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Texas</td><td style=";">Public</td><td style="text-align: right;;">100</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Texas</td><td style=";">Private</td><td style="text-align: right;;">200</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">Florida</td><td style=";">Public</td><td style="text-align: right;;">101</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">Florida</td><td style=";">Private</td><td style="text-align: right;;">200</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">Texas</td><td style=";">Public</td><td style="text-align: right;;">102</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style=";">Texas</td><td style=";">Private</td><td style="text-align: right;;">200</td><td style="text-align: right;;"></td><td style="text-align: right;;"></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 #BBB;border-top:none;text-align: center;background-color: #DAE7F5;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>Array 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: #BBB"><thead><tr style=" background-color: #DAE7F5;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: #DAE7F5;color: #161120">E3</th><td style="text-align:left">{=SUM(<font color="Blue">IF(<font color="Red">FREQUENCY(<font color="Green">IF(<font color="Purple">A2:A9=E1,IF(<font color="Teal">$B$2:$B$9=E2,IF(<font color="#FF00FF">$C$2:$C$9<>"",MATCH(<font color="Navy">$C$2:$C$9,$C$2:$C$9,0</font>)</font>)</font>)</font>),ROW(<font color="Purple">$B$2:$B$9</font>)-ROW(<font color="Purple">$B$2</font>)+1</font>),$C$2:$C$9</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 

Estimator_J

New Member
Joined
Nov 23, 2016
Messages
4
It worked beautifully! Thank you!
Hi,

Take a look at this and see if this will help:

ABCDE
1statestatusamountFlorida
2FloridaPublic100Public
3FloridaPrivate200201
4TexasPublic100
5TexasPrivate200
6FloridaPublic101
7FloridaPrivate200
8TexasPublic102
9TexasPrivate200

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
E3{=SUM(IF(FREQUENCY(IF(A2:A9=E1,IF($B$2:$B$9=E2,IF($C$2:$C$9<>"",MATCH($C$2:$C$9,$C$2:$C$9,0)))),ROW($B$2:$B$9)-ROW($B$2)+1),$C$2:$C$9))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 

Watch MrExcel Video

Forum statistics

Threads
1,129,590
Messages
5,637,279
Members
416,963
Latest member
samfuge

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
Top