cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mizaskun
Helper I
Helper I

Calculate measure in DAX sum table A * count table B

Good morning,

 

I have the following simplified universe:

mizaskun_2-1623833805546.png

 

The OPINION table stores the opinion (from 1 to 10) of certain users for different questions (each user can answer just once):

mizaskun_3-1623834037683.png

 

The Countries table stores the countries in which each user is relevant:

mizaskun_4-1623834065366.png

 

I want a measure that calculates the average opinion of each user * count of the user in the table countries:

 

For example, if I had a table by question, the result shoud be calculated like this:

P1: User A (3 * 1) + User B (7 * 2) + User C (5 * 3) + User D (2 * 0)  / (1+2+3+0) = 5,33

P2: User A(9 * 1) + User B (5 * 2)  / (1+2) = 6,33

 

Any suggestion? 

 

Thank you so much! 

 

1 ACCEPTED SOLUTION
PaulOlding
Solution Supplier
Solution Supplier

Here's a measure that returns your expected results for the example dataset
 
Average Opinion =
VAR _OpinionsWithCount =
ADDCOLUMNS(
OPINION,
"@Count", COUNTROWS(RELATEDTABLE(COUNTRIES))
)
VAR _Numerator = SUMX(_OpinionsWithCount, OPINION[VALUE] * [@Count])
VAR _Denominator = SUMX(_OpinionsWithCount, [@Count])
VAR _Result = DIVIDE(_Numerator, _Denominator)
RETURN
_Result

View solution in original post

2 REPLIES 2
PaulOlding
Solution Supplier
Solution Supplier

Here's a measure that returns your expected results for the example dataset
 
Average Opinion =
VAR _OpinionsWithCount =
ADDCOLUMNS(
OPINION,
"@Count", COUNTROWS(RELATEDTABLE(COUNTRIES))
)
VAR _Numerator = SUMX(_OpinionsWithCount, OPINION[VALUE] * [@Count])
VAR _Denominator = SUMX(_OpinionsWithCount, [@Count])
VAR _Result = DIVIDE(_Numerator, _Denominator)
RETURN
_Result

View solution in original post

daxer
Solution Sage
Solution Sage

Your model is worse than you might think. You have to change it.

 

daxer_0-1623843444033.png

daxer_1-1623843536395.png <-- This is what should be visible in the Fields pane

daxer_2-1623843582229.png

And measures:

# User Countries = 
CALCULATE(
    DISTINCTCOUNT( UserCountryBridge[CountryID] ),
    REMOVEFILTERS( Countries )
)

Opinion Value = 
var UserAvgValueWithCountryCounts =
    ADDCOLUMNS(
        DISTINCT( Users[UserID] ),
        "@AverageValue",
            CALCULATE(
                AVERAGE( Opinions[Value] )
            ),
        "@CountryCount",
            CALCULATE(
                DISTINCTCOUNT( UserCountryBridge[CountryID] ),
                REMOVEFILTERS( Countries )
            )
    )
var Result = 
    DIVIDE(
        SUMX(
            UserAvgValueWithCountryCounts,
            [@AverageValue] * [@CountryCount]
        ),
        SUMX(
            UserAvgValueWithCountryCounts,
            [@CountryCount] * (1 - ISBLANK( [@AverageValue] ) )
        )
    )
return
    Result

Please do understand the logic of the measure in all the situations you'll be using it in. If in some of them you don't get what you need, then modify the measure to your heart's content.

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

Get Ready for Power BI Dev Camp

Power BI Dev Camp - September 30th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!

PowerPlatform 768x460.png

Microsoft Learn

Check out our new Discover Your Career Path blog post series and get all the details.