Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
Adam_Cromie
Frequent Visitor

Monthly Weighted Average with a filter

Hi, 

I need to created a weighted average visual using the below example data

SegmentDate  AccountRateBalance
West1/01/20211230.7726 $804.86
West1/01/20214560.6198 $484.39
West1/02/20211230.0565 $607.85
West1/02/20214560.8504 $587.12
West1/03/20211230.3875 $701.91
West1/03/20214560.9706 $484.95
East1/01/20217890.6573 $668.76
East1/01/20211010.6411 $586.13
East1/02/20217890.2642 $438.20
East1/02/20211010.6951 $111.90
East1/03/20217890.3067 $790.21
East1/03/20211010.2478 $407.28


The Base is Rate.
Weight is Balance, aggregated across all accounts within each month. 
The visual will filter by Segment and the weighted average will need to update for the filter. 

For instance, with the filter Segment = "West", the desired table would look like this

SegmentDate  AccountRateBalanceTotalWeightWeighted Value
West1/01/20211230.7726 $804.86 $1,289.25     0.62        0.48
West1/01/20214560.6198 $484.39 $1,289.25     0.38        0.23
West1/02/20211230.0565 $607.85 $1,194.97     0.51        0.03
West1/02/20214560.8504 $587.12 $1,194.97     0.49        0.42
West1/03/20211230.3875 $701.91 $1,186.86     0.59        0.23
West1/03/20214560.9706 $484.95 $1,186.86     0.41        0.40

Total is a sum of Balance, summarised by Date, Weight is Balance/Total and Weighted Value is Weight*Rate.

The visual data for "West" would look like this

 Weighted Average
1/01/2021     0.72
1/02/2021     0.45
1/03/2021     0.63

Where Weighted Average is the sum of the Weighted Values for each Date.


Any help is appreciated, thanks.

1 ACCEPTED SOLUTION
v-nuoc-msft
Community Support
Community Support

Hi @Adam_Cromie 

 

For your question, here is the method I provided:

 

Here's some dummy data

 

"Table"

vnuocmsft_0-1709099275705.png

 

Create measures.

 

Total = 
CALCULATE(
    SUM('Table'[Balance]), 
    FILTER(
        ALLEXCEPT('Table', 'Table'[Segment]), 
        'Table'[Date] = MAX('Table'[Date])
    )
)

 

Weight = DIVIDE(SELECTEDVALUE('Table'[Balance]), 'Table'[Total])

 

Weighted Value = SELECTEDVALUE('Table'[Rate]) * 'Table'[Weight]

 

Weighted Average = 
SUMX(
    FILTER(
        ALLSELECTED('Table'), 
        'Table'[Date] = MAX('Table'[Date])
    ), 
    'Table'[Weighted Value]
)

 

Here is the result.

 

vnuocmsft_1-1709099515465.png

 

Regards,

Nono Chen

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

1 REPLY 1
v-nuoc-msft
Community Support
Community Support

Hi @Adam_Cromie 

 

For your question, here is the method I provided:

 

Here's some dummy data

 

"Table"

vnuocmsft_0-1709099275705.png

 

Create measures.

 

Total = 
CALCULATE(
    SUM('Table'[Balance]), 
    FILTER(
        ALLEXCEPT('Table', 'Table'[Segment]), 
        'Table'[Date] = MAX('Table'[Date])
    )
)

 

Weight = DIVIDE(SELECTEDVALUE('Table'[Balance]), 'Table'[Total])

 

Weighted Value = SELECTEDVALUE('Table'[Rate]) * 'Table'[Weight]

 

Weighted Average = 
SUMX(
    FILTER(
        ALLSELECTED('Table'), 
        'Table'[Date] = MAX('Table'[Date])
    ), 
    'Table'[Weighted Value]
)

 

Here is the result.

 

vnuocmsft_1-1709099515465.png

 

Regards,

Nono Chen

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

Feb2025 NL Carousel

Fabric Community Update - February 2025

Find out what's new and trending in the Fabric community.