cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Termigez
Regular Visitor

AVERAGEX over time intervals

Hello everyone, I want to create a new calculated column that will iterate through my rows and will return an average value for current and past 2 values for each unique name taking into consideration Time 

 

NameTimeAmountEXPECTED RETURNED VALUE
A

10:00

4(can be null or 4)
B10:005(can be null or 5)
A11:003(can be null or 3.5)
B11:001(can be null or 6)
A12:0018 (4+3+1) / 3 = 8/3
B12:00511(5+1+5) / 3 = 11/3
A13:00610 (3+1+6) / 3 = 10/3 
B13:0039 (1+5+3) / 3 = 3
A14:00512 (1+6+5) / 3 = 4 

 

Why I need this? Because I want to create a line chart that will use Time as X axis and for each hour it will show an average value for this hour and two past hours. As you can see above the function for Name = A and Time = 14:00 returns average base on Amount from 12:00, 13:00 and 14:00 where Name = A. It is also important to note that there is more than one date in my data so please have in mind that Name = A, Time = 10:00 can occure multiple times but with different date. So I suppose the challange is to create and index that will take into consideration both Date, Time and Name and then use this Index to interate over Amount? 

 

1 ACCEPTED SOLUTION
V-pazhen-msft
Community Support
Community Support

@Termigez 

You first need to create an Index for the [Time], so you can look back for a range, because Time type is not supported 

 

Index = RANKX('Table',[Time],,ASC,Dense)

Result = CALCULATE(AVERAGE('Table'[Amount]),FILTER('Table',[Name]=EARLIER('Table'[Name])),FILTER('Table','Table'[Index]<=EARLIER('Table'[Index])&&'Table'[Index]>EARLIER('Table'[Index])-3))

 

 

Index and Result.JPG

 

Paul Zheng
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

3 REPLIES 3
V-pazhen-msft
Community Support
Community Support

@Termigez 

You first need to create an Index for the [Time], so you can look back for a range, because Time type is not supported 

 

Index = RANKX('Table',[Time],,ASC,Dense)

Result = CALCULATE(AVERAGE('Table'[Amount]),FILTER('Table',[Name]=EARLIER('Table'[Name])),FILTER('Table','Table'[Index]<=EARLIER('Table'[Index])&&'Table'[Index]>EARLIER('Table'[Index])-3))

 

 

Index and Result.JPG

 

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

amitchandak
Super User
Super User

@Termigez 

Try one of the two as columns

Avg  = avergageX(filter(table,table[Name] =earlier(table[Name]) && table[time] <=earlier(table[time])),table[Amount])

Avg  = avergageX(filter(table,table[Name] =earlier(table[Name]) && table[time] <earlier(table[time])),table[Amount])

Unfortunately those formulas don't work. I would appreciate any other ideas. 

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

BizApps LATAM 2023

Business Application LATAM Summit 2023

Join the biggest FREE Business Applications Event in LATAM this February.

Power Platform Bootcamp

Global Power Platform Bootcamp

In this bootcamp we will deep-dive into Microsoft’s Power Platform stack with hands-on sessions and labs, delivered to you by experts and community leaders.