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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
taylorie
Frequent Visitor

calculate variance between two dates based on two values

Hi 

 

I have two tables as per below, I need to calculate the difference between "daily sales" before and after the "Service" was done, using "Bsc Start" and "COM date". The only constant in both tables is the "Corporate ref", and for every date I have a "Daily sale" figure. 

eg. I would need to say the Daily sale difference between Bsc Strat and COM date for the Service TA10, Corporate Ref z765 is xxx

taylorie_1-1677684642085.png

I have tried a couple of options but its not working, I have 2 years worth of daily data and the Corporate Ref are repeating multiple times, same as Service.

Can you please help me add this column?

 

Thanks 

 

1 ACCEPTED SOLUTION
v-tangjie-msft
Community Support
Community Support

Hi @taylorie ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create a measure. 

 

Variance = 
var a=MINX(FILTER(ALL('Table (2)'),[Corporate ref]=MAX('Table'[Corporate ref])&&[Date]>=MAX('Table'[Bsc start])),[Date])
var b=CALCULATE(SUM('Table (2)'[Daily sale]),'Table (2)'[Date]=a)
return ABS(CALCULATE(SUM('Table (2)'[Daily sale]),'Table (2)'[Date]=a+1)-b)

 

(3) Then the result is as follows.

vtangjiemsft_1-1677826990927.png

Best Regards,

Neeko Tang

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

3 REPLIES 3
v-tangjie-msft
Community Support
Community Support

Hi @taylorie ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create a measure. 

 

Variance = 
var a=MINX(FILTER(ALL('Table (2)'),[Corporate ref]=MAX('Table'[Corporate ref])&&[Date]>=MAX('Table'[Bsc start])),[Date])
var b=CALCULATE(SUM('Table (2)'[Daily sale]),'Table (2)'[Date]=a)
return ABS(CALCULATE(SUM('Table (2)'[Daily sale]),'Table (2)'[Date]=a+1)-b)

 

(3) Then the result is as follows.

vtangjiemsft_1-1677826990927.png

Best Regards,

Neeko Tang

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

@v-tangjie-msft Hi and thank you, I have applied the measure to my data but I noticed the COM date is not acounted for in this. I have cheched the data but its not working. see below from my tables.

 

This is the result

taylorie_4-1678986111825.png

 

 

This are the actual data from the database

taylorie_3-1678986098500.png

 

Difference = var a=MINX(FILTER(ALL('leakage data 2018'),[Corporate Reference]=MAX('Sheet1'[DMA])&&[Date]>=MAX('Sheet1'[Bsc start])),[Date])
var b=CALCULATE(SUM('leakage data 2018'[Daily Leakage (m³/d)]),'leakage data 2018'[Date]=a)
return ABS(CALCULATE(SUM('leakage data 2018'[Daily Leakage (m³/d)]), 'leakage data 2018'[Date]=a+1)-b)

 

I think I maybe missing something?

 

Thank you!

Hi @taylorie ,

 

Please try changing the column about dates to the same format. Please check the data model as shown in the following figure. If that doesn't help, can you provide a PBIX file (take care to protect your data privacy).

vtangjiemsft_0-1679036060027.pngvtangjiemsft_1-1679036074577.png

 

Best Regards,

Neeko Tang

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.