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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
MHTANK
Helper III
Helper III

Difference with previous Date's Value

ss0.png

This is My Data:

I export this in Power BI. 

Then I create below matrix:

ss 1.png

Here ,

DD_MM = FORMAT(Sheet1[Date], "DD-MMM")

Avg_Value = AVERAGE(Sheet1[Value])

I want below output:

ss2.png

I explain term one by one:

1) Previous_Value = This value is previous date's value in same category.

2) Diff = This is the difference between Previous_Value and Avg_Value.

 

By this I can see what is the difference between day to day values.

So, How I can get this result? Please Help me.

2 ACCEPTED SOLUTIONS

Try

Previous Value =
VAR BaseTable =
    CALCULATETABLE (
        SUMMARIZE ( Sheet1, Sheet1[Date], Sheet1[Category] ),
        ALLSELECTED ( Sheet1 )
    )
VAR PrevRow =
    OFFSET (
        -1,
        BaseTable,
        ORDERBY ( Sheet1[Date], ASC ),
        PARTITIONBY ( Sheet1[Category] )
    )
VAR Result =
    CALCULATE ( [Avg_Value], PrevRow )
RETURN
    Result

View solution in original post

ajohnso2
Super User
Super User

Firstly i created a measure for the average value 

 

 

AverageValue = 
AVERAGE(TestTable[Value])

 

 

Then a new measure for the previous row value based on max date in each category

 

 

PrevAverageValue = 
VAR CurrentCategory = MAX('TestTable'[Category])  -- Get the current row's category
VAR CurrentDate = MAX('TestTable'[Date])  -- Get the current row's date
VAR PrevDate = 
    CALCULATE(
        MAX('TestTable'[Date]),
        FILTER(
            ALL('TestTable'),  -- Ignore any filters (e.g., from the matrix row context)
            'TestTable'[Category] = CurrentCategory && 
            'TestTable'[Date] < CurrentDate  -- Get the previous date for the same category
        )
    )  -- Find the previous date for the same category
RETURN
    CALCULATE(
        [AverageValue],  -- Get the value for the previous date
        'TestTable'[Date] = PrevDate && 'TestTable'[Category] = CurrentCategory
    )

 

 

Now you can create a new measure to display your variance.

 

Variance = 
VAR _Numerator = [AverageValue]
VAR _Denominator = [PrevAverageValue]

RETURN 
_Numerator - _Denominator // Abs value
// DIVIDE((_Numerator -_Denominator), _Denominator, 0) // Variance %

ajohnso2_1-1732030454759.png

 

 

View solution in original post

6 REPLIES 6
ajohnso2
Super User
Super User

Firstly i created a measure for the average value 

 

 

AverageValue = 
AVERAGE(TestTable[Value])

 

 

Then a new measure for the previous row value based on max date in each category

 

 

PrevAverageValue = 
VAR CurrentCategory = MAX('TestTable'[Category])  -- Get the current row's category
VAR CurrentDate = MAX('TestTable'[Date])  -- Get the current row's date
VAR PrevDate = 
    CALCULATE(
        MAX('TestTable'[Date]),
        FILTER(
            ALL('TestTable'),  -- Ignore any filters (e.g., from the matrix row context)
            'TestTable'[Category] = CurrentCategory && 
            'TestTable'[Date] < CurrentDate  -- Get the previous date for the same category
        )
    )  -- Find the previous date for the same category
RETURN
    CALCULATE(
        [AverageValue],  -- Get the value for the previous date
        'TestTable'[Date] = PrevDate && 'TestTable'[Category] = CurrentCategory
    )

 

 

Now you can create a new measure to display your variance.

 

Variance = 
VAR _Numerator = [AverageValue]
VAR _Denominator = [PrevAverageValue]

RETURN 
_Numerator - _Denominator // Abs value
// DIVIDE((_Numerator -_Denominator), _Denominator, 0) // Variance %

ajohnso2_1-1732030454759.png

 

 

Yes, This is also work.
Thank you so much to you too.👍

johnt75
Super User
Super User

You could create a measure like

Previous Value =
VAR PrevRow =
    OFFSET (
        -1,
        ALLSELECTED ( Sheet1 ),
        ORDERBY ( Sheet1[Date], ASC ),
        PARTITIONBY ( Sheet1[Category] )
    )
VAR Result =
    CALCULATE ( [Avg_Value], PrevRow )
RETURN
    Result

and then the diff measure would just be one measure minus the other one.

error comes:

OFFSET's Relation parameter may have duplicate rows. This is not allowed.

Try

Previous Value =
VAR BaseTable =
    CALCULATETABLE (
        SUMMARIZE ( Sheet1, Sheet1[Date], Sheet1[Category] ),
        ALLSELECTED ( Sheet1 )
    )
VAR PrevRow =
    OFFSET (
        -1,
        BaseTable,
        ORDERBY ( Sheet1[Date], ASC ),
        PARTITIONBY ( Sheet1[Category] )
    )
VAR Result =
    CALCULATE ( [Avg_Value], PrevRow )
RETURN
    Result

Ya, It works.

Thank you so much 👍

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

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

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors