cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
yve214
Helper II
Helper II

Get even total average across months

Hi there,

 

I need help with getting an even average across the calendar months counting from the start date adding to 12 months. I have a date table connected to my data table through the "start_date".

 

I just need the average from the total evenly spread across the months starting from the start date for instance, please see result below.

 

Thank you in advance for your help.

 

Data:

producttotal_amtstart_dateend_dateMonths
a1004/1/20203/31/202112
b2001/1/202012/31/202012
c3002/1/20201/31/202112

 

Expected Result:

producttotal_amtstart_dateend_dateMonthsJan-2020feb-2020march-2020April-2020May-2020jun-2020Jul-2020Aug-2020Sept-2020Oct-2020Nov-2020Dec-2020jan-2021feb-2021March-2021
a1004/1/20203/31/202112   8.38.38.38.38.38.38.38.38.38.38.38.3
b2001/1/202012/31/20201216.716.716.716.716.716.716.716.716.716.716.716.7   
c3002/1/20201/31/202112 252525252525252525252525  
1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

Picture2.png

 

Expected result measure: =
VAR monthscount =
    COUNTROWS (
        SUMMARIZE (
            FILTER (
                ALL ( 'Calendar' ),
                'Calendar'[Date] >= MAX ( Data[start_date] )
                    && 'Calendar'[Date] <= MAX ( Data[end_date] )
            ),
            'Calendar'[Month & Year]
        )
    )
VAR totalamount =
    SUM ( Data[total_amt] )
VAR result =
    DIVIDE ( totalamount, monthscount )
RETURN
    IF (
        MIN ( 'Calendar'[Date] ) >= MAX ( Data[start_date] )
            && MAX ( 'Calendar'[Date] ) <= MAX ( Data[end_date] ),
        result
    )

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

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

Picture2.png

 

Expected result measure: =
VAR monthscount =
    COUNTROWS (
        SUMMARIZE (
            FILTER (
                ALL ( 'Calendar' ),
                'Calendar'[Date] >= MAX ( Data[start_date] )
                    && 'Calendar'[Date] <= MAX ( Data[end_date] )
            ),
            'Calendar'[Month & Year]
        )
    )
VAR totalamount =
    SUM ( Data[total_amt] )
VAR result =
    DIVIDE ( totalamount, monthscount )
RETURN
    IF (
        MIN ( 'Calendar'[Date] ) >= MAX ( Data[start_date] )
            && MAX ( 'Calendar'[Date] ) <= MAX ( Data[end_date] ),
        result
    )

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


@Jihwan_Kim Thank you so much. I was able to get my variables similarly to the one you had but I made the mistake of conencting my tables to the data table. This worked perfectly, thank you.

Helpful resources

Announcements
August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 24 without aka link and time 768x460.jpg

Ted's Dev Camp - July 28, 2022

Watch Session 24 of Ted's Dev Camp along with past sessions!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors