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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
JakobH
Frequent Visitor

Lookup multiple conditions in ReportTable

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)

AccountProductPriceListPrice
Customer111180100

 

FactTable

AccountProductPriceCurrency
Customer111180EUR
Customer211190EUR
Customer311190USD
List111100EUR
List11195USD
Customer1112190EUR
List112200EUR
............

 

Thank you for any input here!

1 ACCEPTED SOLUTION
andrewpirie
Resolver II
Resolver II

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:

andrewpirie_0-1675485887002.png

 

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.

View solution in original post

1 REPLY 1
andrewpirie
Resolver II
Resolver II

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:

andrewpirie_0-1675485887002.png

 

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.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors