Sum duplicate values only once and with one criteria (formula needed)

Masha92

Board Regular
Joined
Jan 27, 2019
Messages
51
Office Version
  1. 365
Hello everyone,

I am desperate with this challenge.

1
3
4
3
4
3
6
5
5
2

I need to sum the above column with the below criteria:
1. Sum values only once (as some values will be duplicated)
2. The value must be more than 3.

So I need it as 4+5+6=15

I was able to satisfy the first condition by using sumproduct and countif. But I was not able to fit in the 2nd criteria.

Can you please help?

Thank you in advance!
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}}),
    #"Removed Duplicates" = Table.Distinct(#"Changed Type"),
    #"Filtered Rows" = Table.SelectRows(#"Removed Duplicates", each [Column1] > 3),
    #"Calculated Sum" = List.Sum(#"Filtered Rows"[Column1])
in
    #"Calculated Sum"
 
Upvote 0
Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", Int64.Type}}),
    #"Removed Duplicates" = Table.Distinct(#"Changed Type"),
    #"Filtered Rows" = Table.SelectRows(#"Removed Duplicates", each [Column1] > 3),
    #"Calculated Sum" = List.Sum(#"Filtered Rows"[Column1])
in
    #"Calculated Sum"
Thanks, but I need excel formula.
I am already using VBA to solve this for the time being. But I can only use an excel formula.
 
Upvote 0
I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
Depending on your version ..

22 11 26.xlsm
ABC
111515
23
34
43
54
63
76
85
95
102
Sum
Cell Formulas
RangeFormula
B1B1=SUM(UNIQUE(FILTER(A1:A10,A1:A10>3,0)))
C1C1=SUMPRODUCT((A1:A10>3)*(MATCH(A1:A10,A1:A10,0)=ROW(A1:A10)-ROW(A1)+1),A1:A10)
 
Upvote 0
Solution
Depending on your version ..

22 11 26.xlsm
ABC
111515
23
34
43
54
63
76
85
95
102
Sum
Cell Formulas
RangeFormula
B1B1=SUM(UNIQUE(FILTER(A1:A10,A1:A10>3,0)))
C1C1=SUMPRODUCT((A1:A10>3)*(MATCH(A1:A10,A1:A10,0)=ROW(A1:A10)-ROW(A1)+1),A1:A10)
Works like charm!
Thanks a lot and I will update my account as suggested.
 
Upvote 0

Forum statistics

Threads
1,223,952
Messages
6,175,596
Members
452,658
Latest member
GStorm

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