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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Curtw01
Frequent Visitor

Calculating difference between two column values in matrix

Hi,

 

First ever post to the forum (I believe this is the correct place to post) so excuse me if there is too much/too little information provided. 

 

I have a requirement whereby I need to display, on a matrix, the monthly share of orders per product over a given period. And directly below on a separate matrix, show the movement month on month for each product. 

 

Example of what I'm trying to get to below. 

 

No. of Orders

 JanFebMarAprMayJunJulAugSepOctNovDec
Product 1675449144694507155185681607667396107673756563966
Product 2684550024704507854325535615867156039686255303892
Product 3695648434663502653545463604665676019697258454053
Product 4694149084575518855175452594367585918684457643997
Product 5664448644713510153345542610266946064675256784123
Grand Total341402453123349254642715527673303253347330147341672847320031

 

Share of Orders

  JanFebMarAprMayJunJulAugSepOctNovDec
Product 1 19.78%20.03%20.10%19.91%20.32%20.53%20.04%20.13%20.26%19.72%19.86%19.80%
Product 2 20.05%20.39%20.15%19.94%20.00%20.00%20.31%20.06%20.03%20.08%19.42%19.43%
Product 3 20.37%19.74%19.97%19.74%19.72%19.74%19.94%19.62%19.97%20.41%20.53%20.23%
Product 4 20.33%20.01%19.59%20.37%20.32%19.70%19.60%20.19%19.63%20.03%20.24%19.95%
Product 5 19.46%19.83%20.19%20.03%19.64%20.03%20.12%20.00%20.11%19.76%19.94%20.58%

 

MoM Variance

 JanFebMarAprMayJunJulAugSepOctNovDec
Product 1 0.25%0.07%-0.19%0.41%0.21%-0.49%0.10%0.12%-0.54%0.15%-0.07%
Product 2 0.34%-0.24%-0.20%0.06%0.00%0.31%-0.25%-0.03%0.05%-0.66%0.01%
Product 3 -0.63%0.23%-0.23%-0.02%0.02%0.20%-0.32%0.35%0.44%0.12%-0.29%
Product 4 -0.32%-0.41%0.78%-0.06%-0.62%-0.10%0.59%-0.56%0.40%0.21%-0.29%
Product 5 0.37%0.36%-0.15%-0.39%0.38%0.10%-0.12%0.12%-0.35%0.18%0.64%

 

Example of raw data structure below. (data below will not equal the above as its just a sample of the data)

 

Product Date Orders
Product 1 01/11/2021 1
Product 2 01/11/2021 1
Product 3 01/09/2019 1
Product 4 01/12/2021 1
Product 5 01/06/2022 1
Product 1 01/03/2019 2
Product 2 01/07/2020 1
Product 3 01/11/2019 1
Product 4 01/11/2021 1
Product 5 01/02/2021 1
Product 1 01/03/2020 1
Product 2 01/04/2021 1
Product 3 01/05/2021 1
Product 4 01/06/2020 1
Product 5 01/08/2021 2
Product 1 01/09/2020 2
Product 2 01/10/2021 1
Product 3 01/01/2019 1
Product 4 01/11/2019 2
Product 5 01/11/2019 2
Product 1 01/12/2019 1
Product 2 01/06/2020 1
Product 3 01/07/2020 1
Product 4 01/09/2022 1
Product 5 01/10/2022 1
Product 1 01/11/2022 1
Product 2 01/01/2019 1
Product 3 01/10/2020 1
Product 4 01/02/2022 1
Product 5 01/03/2022 1

 

I can comfortably plot the sum of orders each month for each product and also the share (%) of orders per month per product on a matrix. However, the variance month on month is where I'm having difficulty. 

 

Can anyone advise please? 

 

Much appreciated,

Curt

2 ACCEPTED SOLUTIONS

@Curtw01 

Please try

MoM Variance =
VAR CurrentValue = [No. of Orders]
VAR CuurentYearMonth =
MAX ( 'Date'[YearMonthNum] )
VAR PreviousValue =
CALCULATE (
[No. of Orders],
'Date'[YearMonthNum] = CuurentYearMonth - 1,
ALL ( 'Date' )
)
RETURN
IF (
NOT ISBLANK ( PreviousValue ),
DIVIDE ( CurrentValue - PreviousValue, CurrentValue )
)

View solution in original post

@Curtw01 
You should be using a YearMonthNum column which is supposed to be a sequential number such as a dense rank. For example for Jan. 2023 you cannot minus one from 202301 to obtain 202212. Rather you will obtain 202300 which basically has no value in your date table. Therefore, the YearMonthNum is different than the YearMonth column which can start from 1 for example to refer to the very first month in your table and keeps adding 1 for each month after that. You can create such column using

RANKX ( 
'Date',
'Date'[YearMonth],, -- In the form of YYYYMM like 202307
ASC,

Dense
)

View solution in original post

7 REPLIES 7
tamerj1
Super User
Super User

Hi @Curtw01 

is the month placed in the columns of the matrix from a date table? Do you have a YearMonth rank column?

Hi,

 

Yes, in my real world scenario it would be MonthYear in the columns of the matrix and I have a MonthYearNum column in my date table in which to rank. 

@Curtw01 

Please try

MoM Variance =
VAR CurrentValue = [No. of Orders]
VAR CuurentYearMonth =
MAX ( 'Date'[YearMonthNum] )
VAR PreviousValue =
CALCULATE (
[No. of Orders],
'Date'[YearMonthNum] = CuurentYearMonth - 1,
ALL ( 'Date' )
)
RETURN
IF (
NOT ISBLANK ( PreviousValue ),
DIVIDE ( CurrentValue - PreviousValue, CurrentValue )
)

Hi,

 

Revisiting this and hoping you could potentially help further. 

 

When displaying this measure in the matrix it does not seem to show any January values for any year? Any ideas how to get around this? 

@Curtw01 
You should be using a YearMonthNum column which is supposed to be a sequential number such as a dense rank. For example for Jan. 2023 you cannot minus one from 202301 to obtain 202212. Rather you will obtain 202300 which basically has no value in your date table. Therefore, the YearMonthNum is different than the YearMonth column which can start from 1 for example to refer to the very first month in your table and keeps adding 1 for each month after that. You can create such column using

RANKX ( 
'Date',
'Date'[YearMonth],, -- In the form of YYYYMM like 202307
ASC,

Dense
)

Ahh yes that now makes sense, appreciate your help once again! 

Had to tweak slightly but that worked a treat! Thank you very much! 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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