Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi,
I need to created a weighted average visual using the below example data
Segment | Date | Account | Rate | Balance |
West | 1/01/2021 | 123 | 0.7726 | $804.86 |
West | 1/01/2021 | 456 | 0.6198 | $484.39 |
West | 1/02/2021 | 123 | 0.0565 | $607.85 |
West | 1/02/2021 | 456 | 0.8504 | $587.12 |
West | 1/03/2021 | 123 | 0.3875 | $701.91 |
West | 1/03/2021 | 456 | 0.9706 | $484.95 |
East | 1/01/2021 | 789 | 0.6573 | $668.76 |
East | 1/01/2021 | 101 | 0.6411 | $586.13 |
East | 1/02/2021 | 789 | 0.2642 | $438.20 |
East | 1/02/2021 | 101 | 0.6951 | $111.90 |
East | 1/03/2021 | 789 | 0.3067 | $790.21 |
East | 1/03/2021 | 101 | 0.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
Segment | Date | Account | Rate | Balance | Total | Weight | Weighted Value |
West | 1/01/2021 | 123 | 0.7726 | $804.86 | $1,289.25 | 0.62 | 0.48 |
West | 1/01/2021 | 456 | 0.6198 | $484.39 | $1,289.25 | 0.38 | 0.23 |
West | 1/02/2021 | 123 | 0.0565 | $607.85 | $1,194.97 | 0.51 | 0.03 |
West | 1/02/2021 | 456 | 0.8504 | $587.12 | $1,194.97 | 0.49 | 0.42 |
West | 1/03/2021 | 123 | 0.3875 | $701.91 | $1,186.86 | 0.59 | 0.23 |
West | 1/03/2021 | 456 | 0.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.
Solved! Go to Solution.
Hi @Adam_Cromie
For your question, here is the method I provided:
Here's some dummy data
"Table"
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.
Regards,
Nono Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Adam_Cromie
For your question, here is the method I provided:
Here's some dummy data
"Table"
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.
Regards,
Nono Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
112 | |
105 | |
98 | |
38 | |
30 |