Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hi there, I am new to Power Bi and DAX and am having difficulty selecting and displaying records based on a single value that exists in multiple columns in my data set. I want to select a value for customerid from one table and then select all records from another table that contain the value in any of the three columns and then display the records based only on one of the three columns.
For example. Get all records that contain the value “1” in the Soldto or EndCust or ShipTo columns then be able to display all records either by Soldto with Value 1 or EndCust with Value1 or ShipTo with value1 as well as show all records that contain the value in any of the three columns
I have two tables: Customerid and Sales. The customer ID table contains the list of values which will be used to filter the second table. Only one value will be selected at a time.
I used shipTo as the many relationship but I could have also used SoldTo or EndCust fields as the values from Customerid will match to any of these.
View of visuals with nothing selected
View of data with Customer ID of 1 (note this only includes records that have 1 in the shipto column due to the relationship between customerid and sales).
Output again (this does not show the record that has a value of 1 in endcust. Again this makes sense based on the relationship.)
The sales data does not contain a CustomerID column and the three fields that do have the values may not have all of the id numbers in them.
The actual dataset I will be working with is huge so I don’t want to create several different tables if it can be avoided. Any suggestions for how I can accomplish selecting a value for customerid from one table and then select all records from another table that contains the value in any of the three columns and then display the records based only on one of the three columns, or all three, and combinations thereof.
Any assitance would be greatly appreciated. Thanks
Solved! Go to Solution.
@juncco888 In this case you don't want/need ANY relationship between the CustomerID table and Sales table.
Create a measure:
Selected Customer Sales =
SUMX(
FILTER(Sales,
Sales[ShipTo] IN VALUES(CustID[CustID])
|| Sales[SoldTo] IN VALUES(CustID[CustID])
|| Sales[EndCust] IN VALUES(CustID[CustID])
), Sales[Amount])
Copying DAX from this post? Click here for a hack to quickly replace it with your own table names
Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C
I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com
@AllisonKennedy Thank you so much worked perfectly. Going to incorporate in to my model with the large dataset now.
@juncco888 In this case you don't want/need ANY relationship between the CustomerID table and Sales table.
Create a measure:
Selected Customer Sales =
SUMX(
FILTER(Sales,
Sales[ShipTo] IN VALUES(CustID[CustID])
|| Sales[SoldTo] IN VALUES(CustID[CustID])
|| Sales[EndCust] IN VALUES(CustID[CustID])
), Sales[Amount])
Copying DAX from this post? Click here for a hack to quickly replace it with your own table names
Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C
I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com
User | Count |
---|---|
117 | |
75 | |
62 | |
50 | |
44 |
User | Count |
---|---|
174 | |
125 | |
60 | |
60 | |
57 |