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
jdbuchanan71
Super User
Super User

@Anonymous 

Try this as a start.  Add this calculated column to your QC table.

 

Cal Check Column = 
VAR _Serial = QC[Serial]
VAR _Date = QC[QC Date]
VAR _LastCal = CALCULATE(
    MAX (Calibration[Cal Date]),
    Calibration[Serial] = _Serial,
    Calibration[Cal Date] < _Date
)
RETURN
CALCULATE(
    MAX(Calibration[Cal Xq]),
    Calibration[Serial] = _Serial,
    Calibration[Cal Date] = _LastCal
)-QC[QC Xq]

 

 

Anonymous
Not applicable

@jdbuchanan71 

 

That's definitely a promining start, thanks! I'm getting the error "A single value for column 'Serial' in table 'QC' cannot be determined." due to there being multiple entries in the table for each serial number. Using a MIN or MAX function yields incorrect results, as I think it's picking values associated with different dates in that case. Is there a way to specify that the variable only uses the serial number, date, and Xq from that row?

 

I appreciate the help!

@Anonymous 

You are adding it as a calculated column on the QC table yes?  The VAR will read the current row of the table it is working on.

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!


Anonymous
Not applicable

Hi @richbenmintz,

Apologies for the slow reply! I had been pulled into other projects and this one got backburnered. 

 

I'm using your two-column solution which looks promising, but getting a circular dependency error for the second column when I attempt the DIVIDE function. 

 

Using the information found at https://community.powerbi.com/t5/Desktop/Row-Identifier-within-Power-BI-for-Desktop-Circular-depende... I've been trying to use ALLEXCEPT in the CALCULATE function to fix the error, but haven't had much luck.

 

Thanks again for your help!

Hi @Anonymous,

 

Can you share your Calculated Column formula that is generating the circular dependency?



I hope this helps,
Richard

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

Proud to be a Super User!


Anonymous
Not applicable

The formulas I'm using are essentially what you had suggested above; so column 1 returns the last calibration Xq as intended:

 

 

Last Cal Xq = 
VAR _SERIAL = [SerialNumber]
VAR _RPCDATE = [TestDate]
VAR _MAXDATE = 
    CALCULATE(
        MAX(RECORDS_AD[Cal Date]), 
        FILTER(RECORDS_AD, RECORDS_AD[SerialNumber] = _SERIAL && RECORDS_AD[Cal Date] <= _RPCDATE)
        )
RETURN
    CALCULATE(
        MAX(RECORDS_AD[Xq]), 
        FILTER(RECORDS_AD, RECORDS_AD[SerialNumber] = _SERIAL && RECORDS_AD[Cal Date] = _MAXDATE)
        )

 

 

 

But the second column I'm calling "Off" gives the circular dependency error:

 

 

Off = 
DIVIDE(RECORDS_RP[Xq], RECORDS_RP[Last Cal Xq])-1

 

Hi @Anonymous,

 

What is the difference between the RECORDS_AD and RECORDS_RP Tables? Is RECORDS_RP[Xq] a calculation that references RECORDS_AD[Xq]?



I hope this helps,
Richard

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

Proud to be a Super User!


Anonymous
Not applicable

Apologies, I should have made the language consistent with the example above - RECORDS_AD is essentially the Calibration table ("AD" for calibration "adjustment"), and RECORDS_RP is the QC table (RP for "routine performance" check); so my intent is to calculate the difference between each RECORDS_RP[Xq] and the corresponding RECORDS_AD[Xq] from the last calibration adjustment date. 

 

Sorry for the confusion!

Hi @Anonymous,

 

Can you provide a sample pbix with the error?



I hope this helps,
Richard

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

Proud to be a Super User!


can you share your pbix



I hope this helps,
Richard

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

Proud to be a Super User!


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.