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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
sudipghosh
Regular Visitor

Average of Measure results

Hi,

 

I've created a table in PBI desktop which contains a customer ID followed by 7 columns, each column giving the value of a particular measure.  Each measure is quite different, based on their own unique set of tables.  They each represent a percentage score for different customer interactions.

 

I need to create a new column which relresents the "Customer Health" - the average of all of these scores for each customer, ignoring blanks, but I'm finding this really tricky.

 

So for customer ID 16, the average should be:

(0.83 + 98.2 + 100 + 0) / 4 = 49.75%

For customer ID 21:

(47.5 + 90.48 + 100 +0 + 92) / 5 = 66.00%

so on

 

Any help would be much appreciated

 

 

 

Average of measures.png

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

Hi @sudipghosh

If the "7 columns " are columns, please refer to my pbix "Average of Measure results-v1".

 

However, it seems the "7 columns " are 7 measures.

in this scenario, please refer to my pbix "Average of Measure results-v2".

create measures below

CountMeasuresNoBlank =
IF ( COUNTX ( Sheet2, [Measure1] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure2] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure3] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure4] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure5] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure6] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure7] ) <> BLANK (), 1 )


MeasureSum = [Measure1]+[Measure2]+[Measure3]+
                         [Measure4]+[Measure5]+[Measure6]+[Measure7]

average = [MeasureSum]/[CountMeasuresNoBlank]

Or nestet them in one measure

average2 = var CountMeasuresNoBlank =
IF ( COUNTX ( Sheet2, [Measure1] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure2] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure3] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure4] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure5] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure6] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure7] ) <> BLANK (), 1 )
var MeasureSum = [Measure1]+[Measure2]+[Measure3]+[Measure4]+[Measure5]+[Measure6]+[Measure7]   
return [MeasureSum]/[CountMeasuresNoBlank]

2.png

 

 

Best Regards

Maggie

 

View solution in original post

3 REPLIES 3
sudipghosh
Regular Visitor

@v-juanli-msft & @NickolajJessen thanks very much for your help - this has helped me solve the problem.

v-juanli-msft
Community Support
Community Support

Hi @sudipghosh

If the "7 columns " are columns, please refer to my pbix "Average of Measure results-v1".

 

However, it seems the "7 columns " are 7 measures.

in this scenario, please refer to my pbix "Average of Measure results-v2".

create measures below

CountMeasuresNoBlank =
IF ( COUNTX ( Sheet2, [Measure1] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure2] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure3] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure4] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure5] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure6] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure7] ) <> BLANK (), 1 )


MeasureSum = [Measure1]+[Measure2]+[Measure3]+
                         [Measure4]+[Measure5]+[Measure6]+[Measure7]

average = [MeasureSum]/[CountMeasuresNoBlank]

Or nestet them in one measure

average2 = var CountMeasuresNoBlank =
IF ( COUNTX ( Sheet2, [Measure1] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure2] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure3] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure4] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure5] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure6] ) <> BLANK (), 1 )
    + IF ( COUNTX ( Sheet2, [Measure7] ) <> BLANK (), 1 )
var MeasureSum = [Measure1]+[Measure2]+[Measure3]+[Measure4]+[Measure5]+[Measure6]+[Measure7]   
return [MeasureSum]/[CountMeasuresNoBlank]

2.png

 

 

Best Regards

Maggie

 

NickolajJessen
Solution Sage
Solution Sage

 

Measure 1: 

sum function that adds percentages

 

Measure 2:
Count measure that count the number of non blanks (It does this by default)

Measure 3:
Measure 1 divided by measure 2

 

count and average.PNG

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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