Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello all,
New to DAX and struggling to find a measure for this:
I want to add a column to my ReportTable which displays the Listprice for a certain Product. I have to check the rows Product and Currency of the ReportTable and look them up for Account=List in the FactTable, then return Price.
I tried LOOKUPVALUE(), but it does not seem to work here as i am looking up multiple values.
Instead of creating a measure, adding a custom column ListPrice to the FactTable would also work for me, but again struggling to find a solution here.
ReportTable (with filter Account=Customer1 and Product=111)
Account | Product | Price | ListPrice |
Customer1 | 111 | 80 | 100 |
FactTable
Account | Product | Price | Currency |
Customer1 | 111 | 80 | EUR |
Customer2 | 111 | 90 | EUR |
Customer3 | 111 | 90 | USD |
List | 111 | 100 | EUR |
List | 111 | 95 | USD |
Customer1 | 112 | 190 | EUR |
List | 112 | 200 | EUR |
... | ... | ... | ... |
Thank you for any input here!
Solved! Go to Solution.
Here's an example of a measure that would find the ProductPrice from the List account row with the same Product ID and Currency
List Price (SUMX) =
VAR _listPrice =
SUMX(
FactTable
, IF(
FactTable[Account] <> "List"
, CALCULATE(
SELECTEDVALUE(FactTable[ProductPrice])
, FactTable[Account] = "List"
, ALLEXCEPT(
FactTable
, FactTable[Currency]
, FactTable[Product ID]
)
)
)
)
RETURN _listPrice
Here's an example of a calculated column that would show the list price for the current row. For the "List" rows this would be blank.
List Price (Col) =
VAR _listPrice = IF(
FactTable[Account] <> "List"
, CALCULATE(
MIN(FactTable[ProductPrice])
, FactTable[Account] = "List"
, REMOVEFILTERS(
FactTable[Account]
, FactTable[ProductPrice]
)
)
)
RETURN _listPrice
Here's your sample dataset:
Having the list prices in the same table as real sale prices seems like it could be an issue if the future if the types of information you need to record for accounts vs list prices changes in future, or if you need to record changes in list prices and identify the list price as it was at the time of the the sale. The concept of a Type 2 Slowly Changing Dimension could help if that is a concern.
Here's an example of a measure that would find the ProductPrice from the List account row with the same Product ID and Currency
List Price (SUMX) =
VAR _listPrice =
SUMX(
FactTable
, IF(
FactTable[Account] <> "List"
, CALCULATE(
SELECTEDVALUE(FactTable[ProductPrice])
, FactTable[Account] = "List"
, ALLEXCEPT(
FactTable
, FactTable[Currency]
, FactTable[Product ID]
)
)
)
)
RETURN _listPrice
Here's an example of a calculated column that would show the list price for the current row. For the "List" rows this would be blank.
List Price (Col) =
VAR _listPrice = IF(
FactTable[Account] <> "List"
, CALCULATE(
MIN(FactTable[ProductPrice])
, FactTable[Account] = "List"
, REMOVEFILTERS(
FactTable[Account]
, FactTable[ProductPrice]
)
)
)
RETURN _listPrice
Here's your sample dataset:
Having the list prices in the same table as real sale prices seems like it could be an issue if the future if the types of information you need to record for accounts vs list prices changes in future, or if you need to record changes in list prices and identify the list price as it was at the time of the the sale. The concept of a Type 2 Slowly Changing Dimension could help if that is a concern.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
11 | |
9 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
12 | |
11 | |
10 | |
9 |