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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
SebL
Frequent Visitor

Average difference between two MIN dates (Summarizing Measures with Averages)

Hi Guys, 

First post. 

I'm trying to create a measure that calculates the average difference between dates. To make things more complicated, these dates fields come from tables that contain multiple rows for the same "user" and I have to first find the MIN of those dates. On top of that, the measure must determine which dates are available and pick the two to subtract. 

Measure 1 = Min(Table1[Date1])
Measure 2 = Min(Table2[Date2])
Measure 3 = Min(Table3[Date3])

Measure 4 = IF(ISBLANK([Measure 1]),[Measure 2]-[Measure 3],[Measure 1]-[Measure 3])

When I drop Measure 4 into a table to see the value for each user, the values are correct. However, if I remove the User ID and replace it with the Year the user signed up, the values for Measure 4 can't be shown as user averages for those years. The years are not a date used in the measures and reside on the same table as the User ID. 

How can I summarise a measure of this kind as an average? 

Maybe I'm taking the wrong approach to this problem.

1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @SebL

 

From your description, you are wanting to calculate the average of the expression in [Measure 4] over Users in the current filter context. You can use AVERAGEX to do this.

 

Something like this should do the trick (I'm guessing the table containing the User ID column table is called Users):

 

Measure 4 Average over Users =
AVERAGEX (
    VALUES ( Users[User ID] ),
    IF (
        ISBLANK ( [Measure 1] ),
        [Measure 2] - [Measure 3],
        [Measure 1] - [Measure 3]
    )
)

Or this should work as well:

Measure 4 Average over Users v2 =
AVERAGEX (
    Users,
    IF (
        ISBLANK ( [Measure 1] ),
        [Measure 2] - [Measure 3],
        [Measure 1] - [Measure 3]
    )
)

Regards,

Owen

 

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

4 REPLIES 4
OwenAuger
Super User
Super User

Hi @SebL

 

From your description, you are wanting to calculate the average of the expression in [Measure 4] over Users in the current filter context. You can use AVERAGEX to do this.

 

Something like this should do the trick (I'm guessing the table containing the User ID column table is called Users):

 

Measure 4 Average over Users =
AVERAGEX (
    VALUES ( Users[User ID] ),
    IF (
        ISBLANK ( [Measure 1] ),
        [Measure 2] - [Measure 3],
        [Measure 1] - [Measure 3]
    )
)

Or this should work as well:

Measure 4 Average over Users v2 =
AVERAGEX (
    Users,
    IF (
        ISBLANK ( [Measure 1] ),
        [Measure 2] - [Measure 3],
        [Measure 1] - [Measure 3]
    )
)

Regards,

Owen

 

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Thanks, this worked perfectly. 

I'm wondering if I could add a follow-up question.

I now have the average number of days per user being displayed over time. How would I go about creating a measure that displays the percentage of those users that are under a certain threshold of days? 

That's good news 🙂

 

I'm assuming you still have [Measure 4] which can be evaluated per User.

 

To calculate % users under a certain threshold, you can do something like this:

Users under threshold % =
VAR UsersUnderThreshold =
    COUNTROWS ( FILTER ( VALUES ( Users[User ID] ), [Measure 4] < Threshold ) )
VAR TotalUsers =
    DISTINCTCOUNT ( Users[User ID] )
RETURN
    DIVIDE ( UsersUnderThreshold, TotalUsers )

Does that work for you?

 

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

That worked perfectly. 

Thanks for the help! 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.