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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Brandaris
Helper I
Helper I

Looking up the correct value from a table with values per periods, based on a unique date

Hello,,

 

I have the following challenge that I hope you can help me with:

In table "Orders" I have:

- customer ID
- product ID
- order date (dates from 1-1-2019 to 1-3-2021)
- quantity
- amount

 

In the table "COSTPRICES" I have at least 3 different cost prices for each Product ID depending on the date.

For example:

Row 1 the cost price from 1-1-2019 to 1-11-2019;

Row 2 is the costprice from 11/2/2019 to 7/6/2020 and

Row 3 is the costprice from 6/7/2020 until now.

 

The column headings are:
- product ID
- start date
- end date
- cost price

 

NB: There's also a calendar table in the PBIX

 

Now I want to get the correct cost price per order from the cost price table and add it to the order table. That has to be the unique cost price that belongs to the order date and that must match just one of the 3 periods in which this cost price is determined. The LOOKUPVALUE function is obviously not an option, as it does not reference a unique value.

 

What is the best approach to this question?

 

Thank you very much for your help!

 

Sincerely,
Hans

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @Brandaris 

Create a calculated column in the Orders table:

Price =
CALCULATE (
    DISTINCT ( CostPrices[Cost price] ),
    FILTER (
        ALL ( CostPrices[product ID], CostPrices[start date], CostPrices[end date] ),
        CostPrices[product ID] = Orders[product ID]
            && CostPrices[start date] <= Orders[date]
            && CostPrices[end date] > Orders[date]
    )
)

 

SU18_powerbi_badge

Please accept the solution when done and consider giving a thumbs up if posts are helpful. 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

View solution in original post

2 REPLIES 2
AlB
Super User
Super User

Hi @Brandaris 

Create a calculated column in the Orders table:

Price =
CALCULATE (
    DISTINCT ( CostPrices[Cost price] ),
    FILTER (
        ALL ( CostPrices[product ID], CostPrices[start date], CostPrices[end date] ),
        CostPrices[product ID] = Orders[product ID]
            && CostPrices[start date] <= Orders[date]
            && CostPrices[end date] > Orders[date]
    )
)

 

SU18_powerbi_badge

Please accept the solution when done and consider giving a thumbs up if posts are helpful. 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

Dear AIB,

Thank you very much for your quick and super good solution!

To let this solution work correctly, there must be no relationship between the calendar table and the cost price table (containing 2 date columns). Between the order table (with 1 date column) and the calendar table, of course, and fortunately yes ;-).

Instead of the DISTINCT function, I also tried the VALUES function. That works well too.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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

Top Solution Authors