cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Eagle77
Helper IV
Helper IV

Average days between two dates

I try to write a measure which can calculate average days between orderdate and register_orderdate. In slicer two dates can be selected. For example:

 

7.PNG

In my tabular I have a seperate column for date which I use in slicer; dateKey_FK (20210401 , 20210610,...)

 

and in table in report:

 

77.PNG

Can you please guide me how I can write measure for 'Average_registerdate'

1 ACCEPTED SOLUTION
v-henryk-mstf
Community Support
Community Support

Hi @Eagle77 ,

 

According to your request, I did the following test: dateKey_FK is a separate date list, and there is no relationship between the two tables. Reference is as follows:

 

avg_day = 
VAR a =
    MIN ( dateKey_FK[Date] )
VAR b =
    MAX ( dateKey_FK[Date] )
VAR c =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Orderdate] >= a
                && 'Table'[RegisterOrderdate] <= b
        )
    )
VAR d =
    CALCULATE (
        SUM ( 'Table'[day_diff] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Orderdate] >= a
                && 'Table'[RegisterOrderdate] <= b
        )
    )
RETURN
    d / c

 

v-henryk-mstf_0-1618215739878.png

 

Below is the sample pbix file.


If the problem is still not resolved, please provide detailed error information and let me know immediately. Looking forward to your reply.

Best Regards,
Henry

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-henryk-mstf
Community Support
Community Support

Hi @Eagle77 ,

 

According to your request, I did the following test: dateKey_FK is a separate date list, and there is no relationship between the two tables. Reference is as follows:

 

avg_day = 
VAR a =
    MIN ( dateKey_FK[Date] )
VAR b =
    MAX ( dateKey_FK[Date] )
VAR c =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Orderdate] >= a
                && 'Table'[RegisterOrderdate] <= b
        )
    )
VAR d =
    CALCULATE (
        SUM ( 'Table'[day_diff] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Orderdate] >= a
                && 'Table'[RegisterOrderdate] <= b
        )
    )
RETURN
    d / c

 

v-henryk-mstf_0-1618215739878.png

 

Below is the sample pbix file.


If the problem is still not resolved, please provide detailed error information and let me know immediately. Looking forward to your reply.

Best Regards,
Henry

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

amitchandak
Super User IV
Super User IV

@Eagle77 , This filter is on which date- orderdate or register_orderdate ?

 

you can get Avg as

averageX(Table, Datediff(orderdate, register_orderdate, day))



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

It's based on datekey_FK. 

@Eagle77 , sorry I did not get it yet. But how datekey_FK is related to the data you have shown or how you want it to be related?



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

secondImage

Are You Ready?

Test your skills now with the Cloud Skills Challenge.

Top Solution Authors