Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
I have the below Model.
Table 1: (Sheet 1)
Sheet 1 Table
Table 2: (Score)
Score Table
I have the following measures to display the visual below.
Visual
Solved! Go to Solution.
Hi @Vishnoo ,
You can try to use following measure if it suitable for your scenario:
Mean =
VAR summary =
FILTER (
ADDCOLUMNS (
SUMMARIZE (
Sheet1,
[School Code],
[Academic Year],
[Score],
"CYTS", CALCULATE (
DISTINCTCOUNT ( Sheet1[Candidate ID] ),
FILTER (
ALLSELECTED ( Sheet1 ),
Sheet1[Academic Year] = EARLIER ( Sheet1[Academic Year] )
&& Sheet1[Score] > 120
)
)
),
"SxCYTS", [Score] * [CYTS]
),
[School Code] IN ALLSELECTED ( Sheet1[School Code] )
)
RETURN
AVERAGEX ( summary, [SxCYTS] )
If above not help, please share some sample data for test.
Regards,
Xiaoxin Sheng
Hi @Vishnoo ,
You can try to use following measure if it suitable for your scenario:
Mean =
VAR summary =
FILTER (
ADDCOLUMNS (
SUMMARIZE (
Sheet1,
[School Code],
[Academic Year],
[Score],
"CYTS", CALCULATE (
DISTINCTCOUNT ( Sheet1[Candidate ID] ),
FILTER (
ALLSELECTED ( Sheet1 ),
Sheet1[Academic Year] = EARLIER ( Sheet1[Academic Year] )
&& Sheet1[Score] > 120
)
)
),
"SxCYTS", [Score] * [CYTS]
),
[School Code] IN ALLSELECTED ( Sheet1[School Code] )
)
RETURN
AVERAGEX ( summary, [SxCYTS] )
If above not help, please share some sample data for test.
Regards,
Xiaoxin Sheng
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
| User | Count |
|---|---|
| 92 | |
| 69 | |
| 50 | |
| 40 | |
| 38 |