cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
jttdp
Frequent Visitor

Calculate sums filtered to current row value

Dear community,

 

I have been struggling to create a new calculated column that involves sums filtered to the values of each row.

 

Below is a small example of my challenge. Each row represents a contribution (D) made by a contributor (A) to a recipient (B) in a particular year (C). For each row, I want to calculate the share of that row's contributor (A) of total contributions to that recipient (B) in that year (C).

 

So with this example, according to manual calculations, in 2000, Anne's contributions to Hawaii in 2000 comprised 41% of total contributions to Hawaii that year. I guess this requires filtered sums but I am unsure of the right functions to use.

 

I would appreciate any insights or advice you might have!

 

A. ContributorB. RecipientC. YearD. AmountContributor share of Year Total
BobNew Jersey2000$41,000100%
AnneHawaii2000$23,00041%
AnneHawaii2000$5,00041%
SueHawaii2000$40,00059%
BobNew Jersey2001$56,300100%
BobHawaii2001$42,00081%
AnneHawaii2001$10,00019%

 

 

 

 

1 ACCEPTED SOLUTION
MarkS
Resolver IV
Resolver IV

Hi @jttdp,

For a calculated column this should work

Contributor share of year Total = DIVIDE(
    CALCULATE(SUM(Table1[Amount]),ALL(Table1[Amount]))
    ,CALCULATE(SUM(Table1[Amount]),ALL(Table1[Contributor],Table1[Amount]))
    ,0)

and format as percentage.

View solution in original post

5 REPLIES 5
BraneyBI
Kudo Commander
Kudo Commander

@jttdp- is there a reason you want this as a Calculated column and not a measure?  If a measure works, then @MarkS solution will work for you.  

@jttdp

 

This might work both as a Calculated Column and as a MEASURE

 

=
DIVIDE (
    CALCULATE (
        SUM ( Table1[Amount] ),
        ALLEXCEPT ( Table1, Table1[Contributor], Table1[Recipient], Table1[Year] )
    ),
    CALCULATE (
        SUM ( Table1[Amount] ),
        ALLEXCEPT ( Table1, Table1[Recipient], Table1[Year] )
    )
)

Regards
Zubair

Please try my custom visuals

@MarkS, @BraneyBI and @Zubair_Muhammad, thank you all so much for your prompt responses and advice - they work well as measures!

 

I tried taking it a step further by referring to another table's set of values, unfortunately it will only work for me if all the references are found on the same table... but nonetheless this has been very helpful! Happy Tuesday!

MarkS
Resolver IV
Resolver IV

Hi @jttdp,

For a calculated column this should work

Contributor share of year Total = DIVIDE(
    CALCULATE(SUM(Table1[Amount]),ALL(Table1[Amount]))
    ,CALCULATE(SUM(Table1[Amount]),ALL(Table1[Contributor],Table1[Amount]))
    ,0)

and format as percentage.

View solution in original post

Actually, @MarkS, your calculation will work properly as a measure.  

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

November Power BI Update 768x460.png

Check it Out!

Click here to read more about the November 2021 Updates!

M365 768x460.jpg

Microsoft 365 Collaboration Conference | December 7–9, 2021

Join us, in-person, December 7–9 in Las Vegas, for the largest gathering of the Microsoft community in the world.