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
nenadpekec
Frequent Visitor

Matrix, custom calculation in Total Column

Hello,
I have test data like this:

TestData.jpg


NOTE: you can download pbix file here.

Scenario:
Users are being interviewed and it is possible that the same user gets interviewed multiple times during a month.
Users are providing Yes/No answers (represented by 1 and 0, respectively) in a questionnaire that has multiple questions.

Requirement:
Matrix should display all results for interviews that occured in the selected month, regardless how many questionnaires were submitted.
However, in TOTAL column we need to count how many users answered with Yes on certain question, but using only the latest response. (If there are muliple answers by same users, previos responses should be ignored in the calculation).

So, in the example below, expected Total in the first row should be 2 and in the second row it should be 0.
ExpectedResult.jpg
Please help! 

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi, @nenadpekec 

Please check the below picture and the sample pbix file's link down below.

 

Picture3.png

 

Values Latest Measure =
VAR currentq =
MAX ( 'Table'[Questions] )
VAR currentuser =
MAX ( 'Table'[User] )
VAR latestdate =
CALCULATE (
MAX ( 'Table'[Date] ),
FILTER (
ALLSELECTED ( 'Table' ),
'Table'[Questions] = currentq
&& 'Table'[User] = currentuser
)
)
RETURN
CALCULATE (
SUM ( 'Table'[Value] ),
FILTER (
ALLSELECTED ( 'Table' ),
'Table'[Questions] = currentq
&& 'Table'[User] = currentuser
&& 'Table'[Date] = latestdate
)
)
 
 
Values Latest Measure Total Fix =
IF (
ISFILTERED ( 'Table'[Date] ),
SUM ( 'Table'[Value] ),
SUMX ( VALUES ( 'Table'[User] ), [Values Latest Measure] )
)
 
 
 
 

Hi, My name is Jihwan Kim.


If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.


Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

3 REPLIES 3
Jihwan_Kim
Super User
Super User

Hi, @nenadpekec 

Please check the below picture and the sample pbix file's link down below.

 

Picture3.png

 

Values Latest Measure =
VAR currentq =
MAX ( 'Table'[Questions] )
VAR currentuser =
MAX ( 'Table'[User] )
VAR latestdate =
CALCULATE (
MAX ( 'Table'[Date] ),
FILTER (
ALLSELECTED ( 'Table' ),
'Table'[Questions] = currentq
&& 'Table'[User] = currentuser
)
)
RETURN
CALCULATE (
SUM ( 'Table'[Value] ),
FILTER (
ALLSELECTED ( 'Table' ),
'Table'[Questions] = currentq
&& 'Table'[User] = currentuser
&& 'Table'[Date] = latestdate
)
)
 
 
Values Latest Measure Total Fix =
IF (
ISFILTERED ( 'Table'[Date] ),
SUM ( 'Table'[Value] ),
SUMX ( VALUES ( 'Table'[User] ), [Values Latest Measure] )
)
 
 
 
 

Hi, My name is Jihwan Kim.


If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.


Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thank you, very much!

Anonymous
Not applicable

 

 

// This measure shows how many users
// answered 'Yes' to at least one question
// (and this 'Yes' must be the latest
// answer).
// **Everything is relative to
// the current context, of course.**
// So, if you slice by Question, User and
// Date, you'll replicate the matrix you've
// shown but also the totals will be according
// to your definition.

[Your Measure] =
// We want to count the users whose
// latest answer is 'Yes' to at least
// one question in scope.
var UserQuestionWithLatestResponseDate =
    ADDCOLUMNS(
        SUMMARIZE(
            T,
            T[User],
            T[Question]
        ),
        "@LatestResponseDate",
            CALCULATE( MAX( T[Date] ) )
    )
var CountOfUsersWithAtLeastOneQWithYesA =
    CALCULATE(
        DISTINCTCOUNT( T[User] ),
        TREATAS(
            UserQuestionWithLatestResponseDate,
            T[User],
            T[Question],
            T[Date]
        ),
        KEEPFILTERS( T[Value] = 1 )
    )
return
    CountOfUsersWithAtLeastOneQWithYesA + 0

 

It wolud be equally as easy to write a measure which would count users with all questions (in scope) answered with "Yes." And if you sliced such a measure the way the matrix is, the outcome would be the same as for the measure above.

daxer_0-1622122349905.png

Please bear in mind the definition of the measure when you view the measure's values. The measure is correct and does what you want but you have to read well its description to realize it's doing what it's supposed to. One last screenshot:

daxer_0-1622124219207.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.

Top Solution Authors