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

Average of Measure

Hi, 

In my historical project table I have created the following measure:

TimeSinceModification =
VAR _CurrentDate = TODAY()

VAR _LastIdModification =
    CALCULATE(
            MAX(Audit[ModifiedOn].[Date]),
            FILTER(
                ALLSELECTED(Audit),
                Audit[Id] = MAX(Audit[Id])))

VAR _TimeSinceLastModification =
    DATEDIFF(_LastIdModification,_CurrentDate,DAY)

RETURN
   _TimeSinceLastModification


The measure is showing number of days since the last modification for each project in the table. 
Now I have to create an measure showing the average number of days since last modification. I tried different AverageX,Sumx e.g.
But everytime it is summing incorrect. Doe's anyone have an idea how to solve this problem?
@SpartaBI 


1 ACCEPTED SOLUTION

Hi,

Thank you for your message, and please check the below picture and the attached pbix file whether it suits your requirement.

 

Picture1.png

 

Expected avg measure: =
VAR _maxdatebyIDtable =
    CALCULATETABLE (
        Data,
        TREATAS (
            GROUPBY (
                Data,
                Data[ID],
                "@maxdate", MAXX ( CURRENTGROUP (), Data[Name ModifiedOn] )
            ),
            Data[ID],
            Data[Name ModifiedOn]
        )
    )
RETURN
    DIVIDE (
        SUMX ( _maxdatebyIDtable, Data[Days since modification] ),
        COUNTROWS ( _maxdatebyIDtable )
    )

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

4 REPLIES 4
Jihwan_Kim
Super User
Super User

Hi,

I am not sure how your dataset looks like, but please try something like below and check whether it works for your dataset.

 

expected measure: =
AVERAGEX (
    ADDCOLUMNS (
        VALUES ( 'projecttable'[projectID] ),
        "@datediff", [TimeSinceModification]
    ),
    [@datediff]
)

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


Hi Jihwan,

I have tried to replicate the structure of my data tabel and hope it gives better meaning now:

NikFe_0-1660648414615.png

E.g. you can see that I have filtered 6 unique project. But project 260 have 2 different modification date and it should only calculate the Lates modified. 
So here the correct Average should be (roundet) 5

Hi,

Thank you for your message, and please check the below picture and the attached pbix file whether it suits your requirement.

 

Picture1.png

 

Expected avg measure: =
VAR _maxdatebyIDtable =
    CALCULATETABLE (
        Data,
        TREATAS (
            GROUPBY (
                Data,
                Data[ID],
                "@maxdate", MAXX ( CURRENTGROUP (), Data[Name ModifiedOn] )
            ),
            Data[ID],
            Data[Name ModifiedOn]
        )
    )
RETURN
    DIVIDE (
        SUMX ( _maxdatebyIDtable, Data[Days since modification] ),
        COUNTROWS ( _maxdatebyIDtable )
    )

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


Hi, 

I have implemented your solution and it works perfectly.

Thanks

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.