The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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:
ID | Reg |
1 | abc |
2 | def |
3 | ghi |
4 | jkl |
5 | mno |
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)
Date | table1 id |
16/01/2024 | 1 |
16/01/2024 | 2 |
16/01/2024 | 4 |
17/01/2024 | 1 |
17/01/2024 | 4 |
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:
Date | table1 id |
16/01/2024 | 3 |
16/01/2024 | 5 |
17/01/2024 | 2 |
17/01/2024 | 3 |
17/01/2024 | 5 |
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.
Solved! Go to Solution.
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.
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.
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.
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.
You can create a 'Table3' as following. See sample data and Power BI file in my shared drive link below.
Proud to be a Super User!
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
108 | |
82 | |
77 | |
46 | |
39 |
User | Count |
---|---|
137 | |
108 | |
69 | |
64 | |
53 |