Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
I need to create a table visual with both Table_1 and Table_2 data merged however If Order_ID is included in Table_1 and Table_2 then only include the Table_1 data.
*Things to note both Table_1 and Table_2 can have repeating rows for the same Order_ID if they have multiple company codes and or products codes associated to them.
Solved! Go to Solution.
@PowerBIUser9901 try this
Table_Combine = UNION ( DISTINCT( Table_1 ), DISTINCT( CALCULATETABLE( Table_2, EXCEPT( VALUES( Table_2[Order_Id] ), VALUES( Table_1[Order_Id] ) ) ) ) )
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@PowerBIUser9901 try union and distinct function
Go to modelling tab, data table and add following DAX.
New Table = DISTINCT( UNION ( TABLE1, TABLE2 ) )
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
Hi @parry2k ,
You DAX formula doesn’t address the logic of If Order_ID is included in Table_1 and Table_2 then only include the Table_1 row data.
Notice in the picture below by using your DAX formula if an Order_ID is in both Table_1 and Table_2 then it shows all row data associated to that Order_ID from both tables rather than just Table_1.
@PowerBIUser9901 what happens if one order has multiple product and company code for same order in table1, which row would you like to get in that case? What is the bussines logic to which order row to keep?
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
If Table_1 Order_ID has multiple Product codes and Company codes associated to them then the end result should be a table of the same Order_ID repeating for each association such as the Desired Output table I showed above.
@PowerBIUser9901 I'm bit lost here, the image you showed is after using solution I provided. send excel sheet with sample data and expected result.
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
Hi @parry2k ,
Take a look at my previous post with the Power BI table created from your DAX formula. Notice that five rows of Order_ID 1200 exist. Table_1 has three occurrences of Order_ID 1200 while Table_2 has two occurreses of Order_ID 1200.
Since the Order_ID exist in both Table_1 and Table_2 the desired output is to only show the three rows of Order_ID 1200 from Table_1. The DAX Formula you suggested UNIONS both tables and shows five rows of Order_ID 1200.
Below is the excel sheet - I color coded it to show how it connects. I Appreciate your assistance.
@PowerBIUser9901 now make sense, so red order even if they have different product id and customer id then one in table 1, you still don't want to include since that order already exists in table 1 regardess of different product and order. will get back on this soon.
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@PowerBIUser9901 try this
Table_Combine = UNION ( DISTINCT( Table_1 ), DISTINCT( CALCULATETABLE( Table_2, EXCEPT( VALUES( Table_2[Order_Id] ), VALUES( Table_1[Order_Id] ) ) ) ) )
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@parry2k That DAX formula you created does exactly what I was looking for. Thank you very much!
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
113 | |
96 | |
91 | |
82 | |
69 |
User | Count |
---|---|
159 | |
125 | |
116 | |
111 | |
95 |