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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Make a column in table A based off of values in a related table b

Hello!

 

I have two tables setup called, "Customer / Lead" and "Estimate." I have setup a relation ship between the two based on a Customer / Lead field. This values in this field have to be uniqe. A customer and or lead can have multple estimates to them.

 

My goal is to setup two columns in the Customer / Lead table with the most recent due date and estimate#. If the customer / lead does not have an estimate, I want it to show up as a N/A.

 

Here is an example of the Customer / Lead Table

Customer / Lead
Customer A
Lead B
Customer C

Here is an example of the Estimate Table

Estimate #     Customer	       DueDate	
1007	       Customer A      2/26/2019
1001 Customer A 3/27/2019
1027 Customer A 1/15/2019
2000 Customer C 2/27/2019

My goal would be for the Customer / Lead table to look like this:

Customer / Lead	    Most Recent Estimate#	Most Recent Estimate Due Date
Customer A 1001   3/27/2019
Lead B N/A N/A
Customer C 2000 2/27/2019

 

If I need to clarify anything, I would be more then happy to! Thanks.

1 ACCEPTED SOLUTION
v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @Anonymous ,

 

I'm afraid you'd better create the measure with the formulas below.

 

Most Recent Estimate Due Date =
VAR a =
    CALCULATE (
        MAX ( 'Table1'[DueDate] ),
        FILTER ( 'Table1', 'Table1'[Customer] = MAX ( 'Table1'[Customer] ) )
    )
RETURN
    IF ( ISBLANK ( a ), "N/A", a )

Most Recent Estimate# =
VAR a =
    CALCULATE (
        MAX ( 'Table1'[Estimate#] ),
        FILTER (
            'Table1',
            'Table1'[DueDate] = MAX ( 'Table1'[DueDate] )
                && 'Table1'[Customer] = MAX ( 'Table1'[Customer] )
        )
    )
RETURN
    IF ( ISBLANK ( a ), "N/A", a )

Here is the output.

 

Capture.PNG

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
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

2 REPLIES 2
Anonymous
Not applicable

Hello!

 

I have two tables setup called, "Customer / Lead" and "Estimate." I have setup a relation ship between the two based on a Customer / Lead field. This values in this field have to be uniqe. A customer and or lead can have multple estimates to them.

 

My goal is to setup two columns in the Customer / Lead table with the most recent due date and estimate#. If the customer / lead does not have an estimate, I want it to show up as a N/A.

 

Here is an example of the Customer / Lead Table

Customer / Lead
Customer A
Lead B
Customer C

Here is an example of the Estimate Table

Estimate #     Customer	       DueDate	
1007	       Customer A      2/26/2019
1001 Customer A 3/27/2019
1027 Customer A 1/15/2019
2000 Customer C 2/27/2019

My goal would be for the Customer / Lead table to look like this:

Customer / Lead	    Most Recent Estimate#	Most Recent Estimate Due Date
Customer A 1001   3/27/2019
Lead B N/A N/A
Customer C 2000 2/27/2019

 

If I need to clarify anything, I would be more then happy to! Thanks.

v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @Anonymous ,

 

I'm afraid you'd better create the measure with the formulas below.

 

Most Recent Estimate Due Date =
VAR a =
    CALCULATE (
        MAX ( 'Table1'[DueDate] ),
        FILTER ( 'Table1', 'Table1'[Customer] = MAX ( 'Table1'[Customer] ) )
    )
RETURN
    IF ( ISBLANK ( a ), "N/A", a )

Most Recent Estimate# =
VAR a =
    CALCULATE (
        MAX ( 'Table1'[Estimate#] ),
        FILTER (
            'Table1',
            'Table1'[DueDate] = MAX ( 'Table1'[DueDate] )
                && 'Table1'[Customer] = MAX ( 'Table1'[Customer] )
        )
    )
RETURN
    IF ( ISBLANK ( a ), "N/A", a )

Here is the output.

 

Capture.PNG

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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