Sum unique distinct invoices
Question:
I have a long table The key is actually col B&C BUT…sometime there are few rows with same key (like rows 3:4 or rows 8:10). I'd like to sum data in column D and to consider same key rows as one row.
Desired result 216
Can I also add condition that Column E=1 ?
Answer:
I highly recommend a pivot table for this task, it is extremely fast which is good if you have lots of data to work with. This article demonstrates a formula that returns a total based on a condition.
Formula in cell E21:
This formula removes duplicate records and sums values in col D.
Explaining the formula in cell E21
To simplify the explanation I am replacing cell references with named ranges. The formula becomes:
Named Ranges
ColB - Â $B$3:$B$18
ColC - Â $C$3:$C$18
ColD - Â $D$3:$D$18
ColE - Â $E$3:$E$18
Step 1 - Filter records equal to condition in cell E21
The equal sign lets you compare the values in column E with the condition in cell C21, this is a logical expression and the result is either TRUE or FALSE (boolean values), however, the SUMPRODUCT function can't work with boolean values. We need to convert the TRUE and FALSe to their numerical equivalents. TRUE = 1 and FALSE = 0 (zero).
--(ColE=$C$21)
--({1; 1; 1; 1; 1; 1; 1; 1; 2; 2; 2; 2; 2; 2; 2; 2}=1)
becomes
--({TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE})
Sumproduct can´t calculate TRUE/FALSE values. Let´s convert values to 1 and 0.
--({TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE})
becomes
{1; 1; 1; 1; 1; 1; 1; 1; 0; 0; 0; 0; 0; 0; 0; 0}
Step 2 - Create an array with values from col D
ColD
becomes
{5; 5; 100; 55; 47; 9; 9; 9; 4; 4; 100; 55; 47; 9; 9; 9}
Step 3 - Count duplicate records
The COUNTIFS function calculates the number of cells across multiple ranges that equals all given conditions.
1/COUNTIFS(ColB, ColB, ColC, ColC, ColD, ColD, ColE, ColE)
becomes
1/{2; 2; 1; 1; 1; 3; 3; 3; 2; 2; 1; 1; 1; 3; 3; 3}
and returns
{0,5; 0,5; 1; 1; 1; 0,333333333333333; 0,333333333333333; 0,333333333333333; 0,5; 0,5; 1; 1; 1; 0,333333333333333; 0,333333333333333; 0,333333333333333}
Step 4 - Return the sum of the products of the corresponding arrays
=SUMPRODUCT(--(ColE=$C$21), ColD, 1/COUNTIFS(ColB, ColB, ColC, ColC, ColD, ColD, ColE, ColE))
becomes
=SUMPRODUCT({1; 1; 1; 1; 1; 1; 1; 1; 0; 0; 0; 0; 0; 0; 0; 0}, {5; 5; 100; 55; 47; 9; 9; 9; 4; 4; 100; 55; 47; 9; 9; 9}, {0,5; 0,5; 1; 1; 1; 0,333333333333333; 0,333333333333333; 0,333333333333333; 0,5; 0,5; 1; 1; 1; 0,333333333333333; 0,333333333333333; 0,333333333333333})
returns 216 in cell E21.
Invoice category
This article demonstrates a macro that copies values between sheets. I am using the invoice template workbook. This macro copies […]
This article demonstrates a basic invoice template I created. It lets you use dropdown lists to quickly select products on […]
This post demonstrates how to: Insert a button to your worksheet Assign a macro to the button Create a basic […]
Unique distinct values category
First, let me explain the difference between unique values and unique distinct values, it is important you know the difference […]
Question: I have two ranges or lists (List1 and List2) from where I would like to extract a unique distinct […]
This article shows how to extract unique distinct values based on a condition applied to an adjacent column using formulas. […]
Excel categories
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.