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
guanel1
Helper I
Helper I

pull in date from another table when the visit name is "XXX"

I have two tables. I want to pull the visit dates from Table 1 into Table 2 but in its own column along the subject # row.

what DAX formula should I use to populated the columns in Yellow? 

 

There is a relationship between Table 2 and Table 1 for the Subject #. Table 2 has all distinct subject #'s listed. 

guanel1_3-1604896157867.png

Basically, lookup the subject # in table 2 on table 1 and pull in the visit date when the visit name is "Baseline". 

 

thank you!

 

 

 

1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@guanel1 , best way is you pivot the table or a copy of it and then merge with table2. Both In power Query

https://radacad.com/pivot-and-unpivot-with-power-bi
https://radacad.com/append-vs-merge-in-power-bi-and-power-query

Videos : pivot:  https://www.youtube.com/watch?v=2HjkBtxSM0g

Merge: https://www.youtube.com/watch?v=zNrmbagO0Oo

 

In Dax you can do like , create 4 columns like given example

baseline = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="Baseline"),[Visit Date])
Procedure = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="Procedure"),[Visit Date])
30 Day = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="30Day"),[Visit Date])
60 Day = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="60Day"),[Visit Date])

View solution in original post

3 REPLIES 3
wdx223_Daniel
Super User
Super User

put this code in calculated column

=SWITCH(Table2[Visit Name],"Baseline",RELATED(Table1[Baseline]),"Procedure",RELATED(Table1[Procedure])"30 Day",RELATED(Table1[30 Day]),"60 Day",RELATED(Table1[60 Day]))

amitchandak
Super User
Super User

@guanel1 , best way is you pivot the table or a copy of it and then merge with table2. Both In power Query

https://radacad.com/pivot-and-unpivot-with-power-bi
https://radacad.com/append-vs-merge-in-power-bi-and-power-query

Videos : pivot:  https://www.youtube.com/watch?v=2HjkBtxSM0g

Merge: https://www.youtube.com/watch?v=zNrmbagO0Oo

 

In Dax you can do like , create 4 columns like given example

baseline = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="Baseline"),[Visit Date])
Procedure = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="Procedure"),[Visit Date])
30 Day = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="30Day"),[Visit Date])
60 Day = max(filter(Table1, Table1[subject#] = table2[subject#] && table1[Visit name]="60Day"),[Visit Date])

Thankyou, this worked. And thanks for posting links to articles and videos that show this process. Those really help the newbie understand how to do this!

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.

Top Solution Authors