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
Ice1341
Helper I
Helper I

Need Dax formula to lookup price table with price change dates

How can integrate the price table into Power BI reports? Need to lookup invoice by shipment date to retrieve the correct price for an upcoming price increase.  

 

Ice1341_0-1627787815097.png

 

2 ACCEPTED SOLUTIONS
ebeery
Solution Sage
Solution Sage

@Ice1341 you've included very little of the info that would be needed to actually properly answer your question.

What is "the price table"?  Does your model have multiple tables?  Are there relationships in your model?

If there are relationships between the tables involved, the RELATED() function may work.  Otherwise, I'd take a look at using LOOKUPVALUE().

View solution in original post

Hi @Ice1341 ,

I created a sample pbix file(see attachment), please check whether that is what you want.

1. Create a calculated column as below under the table PostedSalesLine

List price from product pricing table = 
CALCULATE (
    MAX ( 'Product Price'[LIST PRICE] ),
    FILTER (
        'Product Price',
        'Product Price'[NUMBER] = 'PostedSalesLine'[NUMBER]
            && 'PostedSalesLine'[SHIPMENT DATE] >= 'Product Price'[STARTING DATE]
            && (
                'PostedSalesLine'[SHIPMENT DATE] <= 'Product Price'[ENDING DATE]
                    || 'Product Price'[ENDING DATE] = BLANK ()
            )
    )
)

yingyinr_0-1628065833165.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
Ice1341
Helper I
Helper I

I wanted to get the list price(PostedSalesLine.ListPrice) from the Product Pricing Table. When our price goes up in Oct. I want the list price column in PostedSalesLine table to update accordingly.
I'm sorry for the confusion, I can calculate sales with (qty * list price), but the list price isn't based on product pricing table- which has the starting/ending dates in which the product price will change.

 

Capture.JPG

 

Hi @Ice1341 ,

I created a sample pbix file(see attachment), please check whether that is what you want.

1. Create a calculated column as below under the table PostedSalesLine

List price from product pricing table = 
CALCULATE (
    MAX ( 'Product Price'[LIST PRICE] ),
    FILTER (
        'Product Price',
        'Product Price'[NUMBER] = 'PostedSalesLine'[NUMBER]
            && 'PostedSalesLine'[SHIPMENT DATE] >= 'Product Price'[STARTING DATE]
            && (
                'PostedSalesLine'[SHIPMENT DATE] <= 'Product Price'[ENDING DATE]
                    || 'Product Price'[ENDING DATE] = BLANK ()
            )
    )
)

yingyinr_0-1628065833165.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Worked great thanks!

ebeery
Solution Sage
Solution Sage

@Ice1341 you've included very little of the info that would be needed to actually properly answer your question.

What is "the price table"?  Does your model have multiple tables?  Are there relationships in your model?

If there are relationships between the tables involved, the RELATED() function may work.  Otherwise, I'd take a look at using LOOKUPVALUE().

Right now I'm calculating gross sales with a formula (qty * list price) joined on PostedSalesLIne table. But I want to calculate gross sales by doing a LOOKUPVALUE() using the product/list table above and PostedSalesLine table.  I also have a PostedInvoicetable where I calculate Net Sales, which the calculation will always be correct because it is derived from the invoice itself. 

 

sell to custShip dateQtyUPC NumberGross SalesProd LineList Price
WAL60477/26/202180LIN00221812sun22.65
WAL88515/1/202180LIN00221812sun22.65
WAL89409/30/2021160LIN00223624sun22.65
WAL901410/12/202180LIN00221812sun22.65
       
 PostedSalesLineTable   

Hi @Ice1341 ,

What's your expected result? Do you want to get the sales which equal to qty* list price? And the list price need to retrieve from the product/list table? If yes, there are multiple prices for per No., then which price we need to get? Could you please provide the related calculation logic? By the way, whether there is one relationship created between the field [No.] in product/list table and the field [UPC Number] in PostedSalesLineTable? Thank you.

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.