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
Anonymous
Not applicable

Calculating column values based on date match between tables

I'm attempting to perform a column calculation that will return a value based on the last date of an instrument calibration prior to a quality control check. I have two tables, Calibration and QC, which are related by instrument serial number. For each instrument, there may be multiple calibration dates and quality control checks, during which a result (Xq) is generated. The calculated column (cal check) should compare the difference between the QC check Xq and the Xq result of the last calibration prior to that check. 

 

Example:

Calibration

SerialCal DateCal Xq
10014112/5/19 14:120.081
1001414/12/15 11:360.085
1002906/16/15 9:190.077
1003211/21/19 14:440.082
1003211/21/19 11:120.079
1006701/2/20 11:240.079
1006709/4/18 15:390.081

 

QC

SerialQC DateCal DateQC XqCal Check
1001416/15/194/12/20150.081-4.71%
10014110/15/194/12/20150.082-3.53%
1001412/15/2012/5/20190.079-2.47%
1001416/15/2012/5/20190.08-1.23%
1002906/15/196/16/20150.0792.60%
10029010/15/196/16/20150.0781.30%
1002902/15/206/16/20150.0770.00%
1002906/15/206/16/20150.0770.00%
1003216/15/191/21/20190.08-2.44%
10032110/15/191/21/20190.081-1.22%
1003212/15/201/21/20190.079-3.66%
1003216/15/201/21/20190.0820.00%
1006706/15/199/4/20180.079-2.47%
10067010/15/199/4/20180.077-4.94%
1006702/15/201/2/20200.0823.80%
1006706/15/201/2/20200.0812.53%

 

Fortunately, there is a helper column in the QC table that lists when the last cal was performed. Unfortunately, it is just a date with no time stamp, whereas the Cal Date column in the Calibration table does include the time, and there may be multiple entries from the same day. If I were doing this in Excel, I would use an array to match serial number and cal date between the two tables to return the appropriate Cal Xq, and calculate the difference from there. If they are sorted newest-to-oldest in the table, it will give me the correct result. But, I'm new to Power BI and haven't found a comparable method of doing this with DAX. 

 

Any help would be appreciated, thank you!

1 ACCEPTED SOLUTION

Hi @Anonymous ,

 

here are two calc Columns that I think do the trick

 

 

last Cal Xq val = 
var serial = [Serial]
var calDate = [QC Date]
var maxDate = CALCULATE(MAX('Calibration'[Cal Date]), FILTER(Calibration, Calibration[Serial] = 'QC'[Serial] && Calibration[Cal Date] <= calDate ))
return 
CALCULATE(MAX('Calibration'[Cal Xq]), FILTER('Calibration', Calibration[Serial] = serial && Calibration[Cal Date] = maxDate))

 

 

 

var = DIVIDE([QC Xq], [last Cal Xq val])-1 

 

 

richbenmintz_0-1596130979616.png

 

Hope this Helps


Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!



I hope this helps,
Richard

Did I answer your question? Mark my post as a solution! Kudos Appreciated!

Proud to be a Super User!


View solution in original post

11 REPLIES 11

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.