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

Calculate Percent Change Using Non-Continuous Dates

I am trying to create a calculation to show percent change over time using a date column that is not a continuous date. The data shows total file sizes each time a report is run, but the report can be run on demand so attempts to use functions like PREVIOUSDAY don't really work for me because there are missing days. 

 

DataUsage

SizeReportDate
10010/1/2021
5010/4/2021
2510/7/2021
7510/15/2021
5010/17/2021
12510/18/2021
15010/20/2021
10010/22/2021

 

Given the information above, can anyone tell me the best way to create a table similar to this?

 

ReportDateSizeChange (Current Size - Previous Size)

Percent Change

(Change / Previous Size)

10/1/2021100  
10/4/202150-50-50%
10/7/202125-25-50%
10/15/20217550200%
10/17/202150-25-33%
10/18/202112575150%
10/20/20211502520%
10/22/2021100-50-33%

 

 

 

 

For background, I've attempted a variety ways to get at this calculation without success which I'll outline below.

 

I created a dates table and a previous date column:

 

DatesLoaded = SUMMARIZE(
ALL(DataUsage[ReportDate]),
DataUsage[ReportDate])
 
Row Index Column =
CALCULATE(
COUNTROWS(DatesLoaded),
FILTER(All(DatesLoaded), DatesLoaded [ReportDate] <= EARLIER(DatesLoaded [ReportDate]))
)
 
PreviousDate =
LOOKUPVALUE('DatesLoaded'[ReportDate],'DatesLoaded'[Row Index Column], 'DatesLoaded'[Row Index Column]-1)
 
I created a one to many relationship from DatesLoaded to DataUsage on ReportDate:
 
mrLeyshock_0-1634920560733.png

 

Then I created the following measure:
Previous Size = CALCULATE(SUM(DataUsage[Size]), FILTER(DataUsage, DataUsage[ReportDate]=RELATED(DatesLoaded[PreviousDate])))
 
But I don't get any results in the Previous size measure. 
 
I also tried:
Previous Size = CALCULATE(SUM(DataUsage[Size]), ALLSELECTED(DatesLoadedStatic[PreviousDate]))
 
Which returned only the current size, not the previous.
 
 
If I can get the previous size value to work correctly, I believe the fillowing would take care of the difference and % change columns:
 
Usage Difference =
VAR _CurrentDayUsage = SUM(DataUsage[Size])
VAR _PreviousDayUsage = DataUsage[Previous Size]
VAR _Result = _CurrentDayUsage - _PreviousDayUsage
RETURN _Result
 
Usage Growth = DIVIDE ([Usage Difference], [Previous Size], 0)
1 ACCEPTED SOLUTION
v-yalanwu-msft
Community Support
Community Support

Hi, @mrLeyshock ;

You could modify the measure as follows:

Percent Change = 
var _pre=MAXX(FILTER(ALL('Table'),[ReportDate]= CALCULATE(MAX([ReportDate]),FILTER(ALL('Table'),[ReportDate]<MAX('Table'[ReportDate])))),[Size])
return DIVIDE(MAX([Size])- _pre,_pre)

The final output is shown below:

vyalanwumsft_0-1635126501055.png

Best Regards,
Community Support Team_ Yalan Wu
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

4 REPLIES 4
v-yalanwu-msft
Community Support
Community Support

Hi, @mrLeyshock ;

You could modify the measure as follows:

Percent Change = 
var _pre=MAXX(FILTER(ALL('Table'),[ReportDate]= CALCULATE(MAX([ReportDate]),FILTER(ALL('Table'),[ReportDate]<MAX('Table'[ReportDate])))),[Size])
return DIVIDE(MAX([Size])- _pre,_pre)

The final output is shown below:

vyalanwumsft_0-1635126501055.png

Best Regards,
Community Support Team_ Yalan Wu
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

Thank you for sharing this. It was exactly what I needed. 

To close the loop in this. The example that you provided was perfect for the data sample that I shared. Of course my data was a bit more complex, rather than one row per date with a size value, I actually have many smaller size values for each date that I needed to sum. I was ale to modify the example to make it work.


--CREATED AS A COLUMN

PreviousDate =
VAR _ReportDate = DataUsage[ReportDate]
     VAR _prevDate = CALCULATE(MAX(DataUsage[ReportDate]), FILTER(DataUsage,DataUsage[ReportDate] < _ReportDate))
RETURN
_prevDate


--MEASURES


PreviousSize =
SUMX (
     FILTER (
          ALL ( 'DataUsage' ),
          [ReportDate]
               = CALCULATE (
                    MAX ( [ReportDate] ),
                    FILTER (
                         ALL ( 'DataUsage' ),
                         [ReportDate] < MAX ( 'DataUsage'[ReportDate] )
                    )
               )
     ),
     [Size]
)

PercentChange = DIVIDE([CurrentSize]-[PreviousSize], [PreviousSize])

HotChilli
Super User
Super User

Here's previous size as a column.

PreviousValue = 
VAR _ReportDate = DataUsage[ReportDate]
  VAR _prevDate =  CALCULATE(MAX(DataUsage[ReportDate]), FILTER(DataUsage,DataUsage[ReportDate] < _ReportDate))
RETURN
CALCULATE(SUM(DataUsage[Size]), FILTER(DataUsage,DataUsage[ReportDate] = _prevDate))

Is that enough to get you started?

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

November Power BI Update 768x460.png

Check it Out!

Click here to read more about the November 2021 Updates!

M365 768x460.jpg

Microsoft 365 Collaboration Conference | December 7–9, 2021

Join us, in-person, December 7–9 in Las Vegas, for the largest gathering of the Microsoft community in the world.