Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Prasad1
Helper I
Helper I

Calculating Averages for the same data for different time buckets (Daily/Weekly/Monthly)

Hi

 

I have sales data at invoice date level. I want to have average calculations at 3 time bucket levels on the same data

a) Daily sales average: Total of the daily sales and divide by total number of days (In the example, there are 59 days. Sum of all daily sales = 1770, So daily average = 1770 / 59 = 30

b) Weekly sales average: Arrive at sales total for each week (sum of 7 days dialy sales) and average such week totals => Sum of weekly sales total / no of weeks (in the example, sum of all week sales total = 1770. No of weeks = 9. Average weekly sales = 1770 / 9 = 196.67

c) Monthly sales Average: Arrive at monthly total for each month and average such monthly totals => Sum of monthly sales total / no of months. (in the example, sum of all months sales total = 1770. No of months = 2. Average monthly sales = 1770 / 2 = 885,

 

Please let me know how to do it in PowerBI. Any help is grately appreciated.

 

Thanks

Prasad

 

The simple example is attached here with.

 

Daily, Weekly, Monthly average problem - 1.PNGDaily, Weekly, Monthly average problem - 2.PNG

Daily, Weekly, Monthly average problem - 3.PNGDaily, Weekly, Monthly average problem - 4.PNG

1 ACCEPTED SOLUTION

Hi Xiaoxin Sheng

 

Thank you very much. The result is exactly what is needed. I guess, we can get daily average on the same lines. Let me try and come back to you.

 

Appreciate your help.

 

Regards

Prasad

View solution in original post

2 REPLIES 2
v-shex-msft
Community Support
Community Support

HI @Prasad1,

 

You can check below formula to use formula to get average of current group.

 

Measures:

Current Count = 
SWITCH (
    TRUE (),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Month] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE (ALLSELECTED('Table'), [Quarter], [Month], [Week] ) ),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Month] ), COUNTROWS ( SUMMARIZE (ALLSELECTED('Table'), [Quarter], [Month] ) ),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE ( ALLSELECTED('Table'), [Quarter], [Week] ) ),
    ISFILTERED ( 'Table'[Month] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE ( ALLSELECTED('Table'), [Month], [Week] ) ),
    ISFILTERED ( 'Table'[Quarter] ), COUNTROWS ( ALLSELECTED ( 'Table'[Quarter] ) ),
    ISFILTERED ( 'Table'[Month] ), COUNTROWS ( ALLSELECTED ( 'Table'[Month] ) ),
    ISFILTERED ( 'Table'[Week] ), COUNTROWS ( ALLSELECTED ( 'Table'[Week] ) ),
    COUNTROWS(ALLSELECTED('Table'))
)


Dynamic AVG = 
VAR GroupCount =
SWITCH (
    TRUE (),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Month] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE (ALLSELECTED('Table'), [Quarter], [Month], [Week] ) ),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Month] ), COUNTROWS ( SUMMARIZE (ALLSELECTED('Table'), [Quarter], [Month] ) ),
    ISFILTERED ( 'Table'[Quarter] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE ( ALLSELECTED('Table'), [Quarter], [Week] ) ),
    ISFILTERED ( 'Table'[Month] ) && ISFILTERED ( 'Table'[Week] ), COUNTROWS ( SUMMARIZE ( ALLSELECTED('Table'), [Month], [Week] ) ),
    ISFILTERED ( 'Table'[Quarter] ), COUNTROWS ( ALLSELECTED ( 'Table'[Quarter] ) ),
    ISFILTERED ( 'Table'[Month] ), COUNTROWS ( ALLSELECTED ( 'Table'[Month] ) ),
    ISFILTERED ( 'Table'[Week] ), COUNTROWS ( ALLSELECTED ( 'Table'[Week] ) ),
    COUNTROWS(ALLSELECTED('Table'))
)
RETURN
    DIVIDE ( SUMX ( ALLSELECTED( 'Table' ), [Amount] ), GroupCount, 0 )

Result:

7.PNG

 

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Hi Xiaoxin Sheng

 

Thank you very much. The result is exactly what is needed. I guess, we can get daily average on the same lines. Let me try and come back to you.

 

Appreciate your help.

 

Regards

Prasad

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.