cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
hassaanb_
Frequent Visitor

Difference between values in a single column based on an identifying value

Hi there community!

 

I'm working with a dataset in which I'm trying to display on Customer and Article level the sales Amount. This is done by looking at a set of seperate Excel files all with their own date of uploading (represented by File Date). These seperate files are combined in to one query by using the append queries function, and File Date functions as an identifying column to be able to differentiate between the seperate files that have been combined in to one query.

 

I have built a small dataset to give an idea on what kind of data I'm working with:

 

CustomerDelivery DateArticleAmountFile Date

123-10-20219991001-1-2022
112-12-20219995001-2-2022
130-12-20212124001-3-2022
115-1-20224871501-3-2022
118-3-20222123001-4-2022
212-12-20214763001-1-2022
223-5-20229810001-2-2022
225-5-2022146201-2-2022
230-7-20229995001-3-2022
25-8-20223587001-5-2022
210-10-20224871001-4-2022
315-11-20215645001-1-2022
330-1-20229994001-3-2022
32-2-2022154501-3-2022
324-7-20223088001-5-2022

 

The data will be presented to the user in a matrix similar to the one below:

hassaanb__0-1650359507686.png

 

The user will be expanding this matrix to also get a detailed view on Article level, which would look something like this:

hassaanb__1-1650359555355.png

 

Using the matrices presented above I want to be able to compare values and show the differences. If Customer = 1 this would mean that the first matrix should also show the following values:

  • +400 for the difference between 1-1-2022 and 1-2-2022
  • +50 for the difference between 1-2-2022 and 1-3-2022
  • -250 for the difference between 1-3-2022 and 1-4-2022
  • -300 for the difference between 1-4-2022 and 1-5-2022

Ideally this difference is shown in percentages but to get it calculated in absolute numbers is a start. I have been struggling with this for a while now and I'm reaching out for suggestions as to how I can get a measure/column implemented to reach the desired result.

 

Looking forward to your suggestions and many thanks in advance!

 

1 ACCEPTED SOLUTION
Eyelyn9
Community Support
Community Support

Hi @hassaanb_ ,

 

Please try:

% (Customer level) = 
var _nextDate= MINX(FILTER(ALL('Table'),[Customer]=MAX('Table'[Customer])&& [File Date]>MAX('Table'[File Date])),[File Date])
var _diff=CALCULATE(SUM('Table'[Amount]),FILTER(ALL('Table'), [Customer]=MAX('Table'[Customer]) &&[File Date]=_nextDate ))-SUM('Table'[Amount])
return DIVIDE(_diff,SUM('Table'[Amount]))

Eyelyn9_0-1650598629394.png

Or 

% (Article level) = 
var _nextDate= MINX(FILTER(ALL('Table'),[Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])  && [File Date]>MAX('Table'[File Date])),[File Date])
var _nextSum=CALCULATE(SUM('Table'[Amount]),FILTER(ALL('Table'), [Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])&&[File Date]=_nextDate ))
var _current=CALCULATE(SUM('Table'[Amount]),FILTER('Table', [Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])))
return  DIVIDE( _nextSum-_current, _current)

Eyelyn9_1-1650598685881.png

 

Best Regards,
Eyelyn Qin
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

1 REPLY 1
Eyelyn9
Community Support
Community Support

Hi @hassaanb_ ,

 

Please try:

% (Customer level) = 
var _nextDate= MINX(FILTER(ALL('Table'),[Customer]=MAX('Table'[Customer])&& [File Date]>MAX('Table'[File Date])),[File Date])
var _diff=CALCULATE(SUM('Table'[Amount]),FILTER(ALL('Table'), [Customer]=MAX('Table'[Customer]) &&[File Date]=_nextDate ))-SUM('Table'[Amount])
return DIVIDE(_diff,SUM('Table'[Amount]))

Eyelyn9_0-1650598629394.png

Or 

% (Article level) = 
var _nextDate= MINX(FILTER(ALL('Table'),[Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])  && [File Date]>MAX('Table'[File Date])),[File Date])
var _nextSum=CALCULATE(SUM('Table'[Amount]),FILTER(ALL('Table'), [Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])&&[File Date]=_nextDate ))
var _current=CALCULATE(SUM('Table'[Amount]),FILTER('Table', [Customer]=MAX('Table'[Customer])&&[Article]=MAX('Table'[Article])))
return  DIVIDE( _nextSum-_current, _current)

Eyelyn9_1-1650598685881.png

 

Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 24 without aka link and time 768x460.jpg

Ted's Dev Camp - July 28, 2022

Watch Session 24 of Ted's Dev Camp along with past sessions!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors