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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
swcoop
New Member

Get related records not in a related table

So this ask might be a bit much or not the right idea of how to go about it, but I have three sets of tables (the third may not be needed) and I'm trying to get table 3 to be a list of missing records from table 1, where they don't exist in table 2 for each of the dates in that table.

 

Table 1 is the main set of data and is about vehicles:

IDReg
1abc
2def
3ghi
4jkl
5mno

 

Table 2 is a point in time of that vehicle being not available, by day (if they're in this table they're not available)

Datetable1 id
16/01/20241
16/01/20242
16/01/20244
17/01/20241
17/01/20244

 

Then table 3 I would like to be the inverse of table 2, so for each date I would like to know the vehicles that are available, as an example based on the above:

Datetable1 id
16/01/20243
16/01/20245
17/01/20242
17/01/20243
17/01/20245

 

Logically I can visualise it as: for each unique date that's in table 2, return all ids from table 1 that does not exist in table 2 for that date. But I don't know enough about how to create that in Power BI (or even if that's possible). Hopefully, that makes sense.

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

Hi @swcoop ,

 

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 table.

Table3 = 
 var _a= CROSSJOIN(VALUES('Table2'[Date]),VALUES('Table1'[ID]))
 return  EXCEPT(_a,'Table2')

(3) Then the result is as follows.

vtangjiemsft_0-1705903058303.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

2 REPLIES 2
v-tangjie-msft
Community Support
Community Support

Hi @swcoop ,

 

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 table.

Table3 = 
 var _a= CROSSJOIN(VALUES('Table2'[Date]),VALUES('Table1'[ID]))
 return  EXCEPT(_a,'Table2')

(3) Then the result is as follows.

vtangjiemsft_0-1705903058303.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. 

amustafa
Super User
Super User

You can create a 'Table3' as following. See sample data and Power BI file in my shared drive link below.

 

Table3 =
ADDCOLUMNS(
    CROSSJOIN(Calendar, Table1),
    "Available IDs", IF(
        NOT (COUNTROWS(FILTER(Table2, Table2[Date] = Calendar[Date] && Table2[ID] = Table1[ID])) > 0),
        Table1[ID],
        BLANK()
    ),
    "Unavailable IDs", IF(
        COUNTROWS(FILTER(Table2, Table2[Date] = Calendar[Date] && Table2[ID] = Table1[ID])) > 0,
        Table1[ID],
        BLANK()
    )
)

 

vehicles_availability

 





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

Proud to be a Super User!




Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

AugPowerBI_Carousel

Power BI Monthly Update - August 2024

Check out the August 2024 Power BI update to learn about new features.

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

August Carousel

Fabric Community Update - August 2024

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