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

weighted average date

Hi,

 

I'm working with a sales table that has three main columns: Amount sold; day sold; and day payed. I'd like to know what is the average days that I take between sell a product and be payed, but I would like as well to do a weighted average.

 

It was supposed to be something like this: SUMX( (Amount Sold) * (Day payed - day sold) / (Total Amount sold).

 

How can I do a measure that return me directly this result?

1 ACCEPTED SOLUTION
OwenAuger
Super User I
Super User I

Hi @mpoppes 

Yes, that's exactly the idea.

 

In DAX, I would write something like this:

 

Average days sold-paid =
VAR TotalAmountSold =
    SUM ( Sales[Amount Sold] )
RETURN
    DIVIDE (
        SUMX ( Sales, ( Sales[Day Paid] - Sales[Day Sold] ) * Sales[Amount Sold] ),
        TotalAmountSold
    )

 

Another version that could improve performance depending on distribution of your dates, especially if you have the same pairs of dates occurring repeatedly:

Average days sold-paid =
VAR TotalAmountSold =
    SUM ( Sales[Amount Sold] )
RETURN
    DIVIDE (
        SUMX (
            SUMMARIZE ( Sales, Sales[Day Paid], Sales[Day Sold] ),
            ( Sales[Day Paid] - Sales[Day Sold] )
                * CALCULATE ( SUM ( Sales[Amount Sold] ) )
        ),
        TotalAmountSold
    )

 

Regards,

Owen


Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn

View solution in original post

2 REPLIES 2
OwenAuger
Super User I
Super User I

Hi @mpoppes 

Yes, that's exactly the idea.

 

In DAX, I would write something like this:

 

Average days sold-paid =
VAR TotalAmountSold =
    SUM ( Sales[Amount Sold] )
RETURN
    DIVIDE (
        SUMX ( Sales, ( Sales[Day Paid] - Sales[Day Sold] ) * Sales[Amount Sold] ),
        TotalAmountSold
    )

 

Another version that could improve performance depending on distribution of your dates, especially if you have the same pairs of dates occurring repeatedly:

Average days sold-paid =
VAR TotalAmountSold =
    SUM ( Sales[Amount Sold] )
RETURN
    DIVIDE (
        SUMX (
            SUMMARIZE ( Sales, Sales[Day Paid], Sales[Day Sold] ),
            ( Sales[Day Paid] - Sales[Day Sold] )
                * CALCULATE ( SUM ( Sales[Amount Sold] ) )
        ),
        TotalAmountSold
    )

 

Regards,

Owen


Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn

View solution in original post

Thanks Bro, you were awesome! It worked perfect

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 on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

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

Top Solution Authors
Top Kudoed Authors