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
Anonymous
Not applicable

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
Super User

Hi @Anonymous 

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!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
OwenAuger
Super User
Super User

Hi @Anonymous 

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!
Blog
Twitter
LinkedIn
Anonymous
Not applicable

Thanks Bro, you were awesome! It worked perfect

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