• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Difference from previous [field] in Power BI|Power Pivot|Excel Forum|My Online Training Hub

You are here: Home / Difference from previous [field] in Power BI|Power Pivot|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower PivotDifference from previous [fiel…
sp_PrintTopic sp_TopicIcon
Difference from previous [field] in Power BI
Avatar
Rita Kiss
Member
Members
Level 0
Forum Posts: 10
Member Since:
February 18, 2015
sp_UserOfflineSmall Offline
1
April 12, 2019 - 6:27 pm
sp_Permalink sp_Print

I'm trying to re-create the Difference from previous field pivot table behavior in a Power BI matrix.

ChangeMeasure.pngImage Enlarger

The columns are milestones, organized by date (but not regular intervals).

I'm looking for a way to create a measure that reciprocates the Sales Change behavior from the pivot table and preferably works even if not all milestones are displayed. I tried several ways to create a dynamic rank but I cannot figure out how to use that to calculate the difference from the previous item.

Any help is appreciated. I have attached the Excel and PowerBI file as a reference.

Thank you!

sp_PlupAttachments Attachments
  • sp_PlupImage ChangeMeasure.png (183 KB)
sp_AnswersTopicSeeAnswer See Answer
Avatar
Mynda Treacy
Admin
Level 10
Forum Posts: 4448
Member Since:
July 16, 2010
sp_UserOfflineSmall Offline
2
April 15, 2019 - 3:21 pm
sp_Permalink sp_Print

Hi Rita,

Usually you'd use dates and time intelligence functions for this, but you don't have a date table, so you can add an index column to the Sales table as a reference for the previous milestone. See file attached. Solution based on this.

Mynda

Avatar
Rita Kiss
Member
Members
Level 0
Forum Posts: 10
Member Since:
February 18, 2015
sp_UserOfflineSmall Offline
3
April 16, 2019 - 11:43 pm
sp_Permalink sp_Print

Hi Mynda,

Thank you for sharing!

1. Currently, I have a similar solution implemented (based on MAX in the index column) but that - and your proposed solution as well - only works if all milestones are selected.

2. I can add a date table if that solves the problem. But the periods between the milestones are irregular. Could I still use time intelligence functions?

Thank you!

Rita

Avatar
Rita Kiss
Member
Members
Level 0
Forum Posts: 10
Member Since:
February 18, 2015
sp_UserOfflineSmall Offline
4
April 17, 2019 - 9:29 pm
sp_Permalink sp_Print

Hi Mynda,

I managed to figure it out with a slight tweaking of the variable you provided.

Change Sales = [Typical sales]-
VAR
previousP = CALCULATE(
MAX(Table[Index]),
FILTER(ALLSELECTED(Table),
Table[Index]<MAX(Table[Index])))

RETURN
CALCULATE([Typical sales],
FILTER(
ALLEXCEPT(Table, Table[Slicer]),
Table[Index]=previousP))

Thanks again!

Avatar
Catalin Bombea
Iasi, Romania
Admin
Level 10
Forum Posts: 1810
Member Since:
November 8, 2013
sp_UserOfflineSmall Offline
5
April 18, 2019 - 2:04 pm
sp_Permalink sp_Print sp_EditHistory

Hi Rita,

Indeed, the key is ALLSELECTED. First, calculate the previous row index, based on selected data:

PreviousRowIndex =
CALCULATE(MAX('Sales'[Index]),FILTER(ALLSELECTED(Sales),Sales[Index]<MAX(Sales[Index])))
 
Here is how the Total - Previous Period should look: (includes the calculation of previous index, [PreviousRowIndex] measure is redundant ):
Total - Previous Period = VAR thisperiod = CALCULATE(MAX('Sales'[Index]),FILTER(ALLSELECTED(Sales),Sales[Index]<MAX(Sales[Index])))
RETURN CALCULATE ([Total],FILTER (ALL(sales), [Index] = thisperiod))
 
Or, reference the PreviousRowIndex measure:
Total - Previous Period = VAR thisperiod = [PreviousRowIndex]
RETURN CALCULATE ([Total], FILTER (ALL(sales), [Index] = thisperiod))
 
Just a minor observation: I used your measure as it is, but you should handle the values displayed in Grand Total section, using COUNTROWS to determine the grand total context.
sp_AnswersTopicAnswer
Answers Post
Avatar
Rita Kiss
Member
Members
Level 0
Forum Posts: 10
Member Since:
February 18, 2015
sp_UserOfflineSmall Offline
6
April 23, 2019 - 10:07 pm
sp_Permalink sp_Print

Hi Catalin,

Thank you!

Good point about the Grand Total! In our scenario, this measure is never shown with a grand total (it doesn't make any sense to aggregate up the changes) but I can imagine other scenarios where it's important.

I use this measure in Power BI (and not Power Pivot in Excel) and the data model is a lot more complicated with various slicers and filters being applied so it took quite some time to figure out the right combination of ALL(), ALLSELECTED() and ALLEXCEPT() and the filter directions to make it work.

Thank you both for your support!

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: RAQUEL ACION, Dana Friedt, Shawn Barwick, Nada Perovic, Uwe von Gostomski
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
terimeri dooriyan
Jack Aston
AndyC
Denise Lloyd
michael serna
mashal sana
Tiffany Kang
Leah Gillmore
Sopi Yuniarti
LAFONSO HERNANDEZ
Forum Stats:
Groups: 3
Forums: 24
Topics: 6218
Posts: 27266

 

Member Stats:
Guest Posters: 49
Members: 31901
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.