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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Anonymous
Not applicable

DAX formula to return Average daily value using most recent available values

Hi, I would appreciate help with the following situation:
- I have a 'Table' with 'Items' that have a 'Status' (value between 0 and 1) on various dates

- The dates are not continous and each 'Item' can have its status reported on different dates.
- I have a 'DateTable' with continious dates
I want to achieve the following:
- Firstly, for every date in the DateTable, and every Item, I need to find the most recent status. (Fill in the gaps)
- Secondly, if an Item has no status on an earlier date, Status should be counted as 0
- Lastly, I need a daily average across all Items (Applying whatever filters the user has set)

Sample Data:

DateStatusItem
01-Jan-220.2A
02-Jan-220.3A
03-Jan-220.4A
04-Jan-220.5A
07-Jan-220.6A
10-Jan-220.8A
11-Jan-220.8A
14-Jan-220.9A
16-Jan-221A
02-Jan-220.2B
03-Jan-220.3B
10-Jan-220.4B
12-Jan-220.5B
14-Jan-220.6B
17-Jan-220.8B
19-Jan-220.9B
20-Jan-221B

 

Desired result:

DateABAverage
01-Jan-220.200.1
02-Jan-220.30.20.25
03-Jan-220.40.30.35
04-Jan-220.50.30.4
05-Jan-220.50.30.4
06-Jan-220.50.30.4
07-Jan-220.60.30.45
08-Jan-220.60.30.45
09-Jan-220.60.30.45
10-Jan-220.80.40.6
11-Jan-220.80.40.6
12-Jan-220.80.50.65
13-Jan-220.80.50.65
14-Jan-220.90.60.75
15-Jan-220.90.60.75
16-Jan-2210.60.8
17-Jan-2210.80.9
18-Jan-2210.80.9
19-Jan-2210.90.95
20-Jan-22111
21-Jan-22111
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Dear @Anonymous ,

Thank you! 
I was looking for a solution within DAX only, without the use of Power Query. 
And, in reality my 'Items' are 1000's of varying different IDs, resulting in a huge pivot, what I would like to avoid. 
I have received a working answer on another of my posts of the same question (the original one was originally flagged and removed, hence the double post).
DAX formula to return Average daily value using most recent available values 
I ended up using this DAX measure:

Average = 
AVERAGEX(
    CALCULATETABLE(VALUES('Table'[Item]), ALLEXCEPT('Table', 'Table'[Item])),
    CALCULATE(
        LASTNONBLANKVALUE('DateTable'[Date], MAX('Table'[Status])),
        'DateTable'[Date] <= MAX('DateTable'[Date])
        )+0
    )


Thank you



View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi @Anonymous 

If your problem has been solved , please consider Accept it as the solution to help the other members find it more quickly.

 

Best Regards,
Community Support Team _ Ailsa Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @Anonymous 

Use Pivot in Power Query Editor to return column[A] and column[B] .

Ailsamsft_0-1657246210098.png

Then replace null with 0 .

Ailsamsft_1-1657246280126.png

Then close & apply your changes and go back to Desktop pane , add these fields in a table visual . You will get a result like this .

Ailsamsft_2-1657246350853.png

Create a calculated column to count the average .

Average = ('Table'[A]+'Table'[B])/2

The final result is as shown below .

Ailsamsft_3-1657246430463.png

I have attached my pbix file , you can refer to it .

 

Best Regards,
Community Support Team _ Ailsa Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Dear @Anonymous ,

Thank you! 
I was looking for a solution within DAX only, without the use of Power Query. 
And, in reality my 'Items' are 1000's of varying different IDs, resulting in a huge pivot, what I would like to avoid. 
I have received a working answer on another of my posts of the same question (the original one was originally flagged and removed, hence the double post).
DAX formula to return Average daily value using most recent available values 
I ended up using this DAX measure:

Average = 
AVERAGEX(
    CALCULATETABLE(VALUES('Table'[Item]), ALLEXCEPT('Table', 'Table'[Item])),
    CALCULATE(
        LASTNONBLANKVALUE('DateTable'[Date], MAX('Table'[Status])),
        'DateTable'[Date] <= MAX('DateTable'[Date])
        )+0
    )


Thank you



Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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