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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
NotVeryGoodatBI
Frequent Visitor

LOOKUPVALUE with ID and Date Filters

 
Hello, I am a little new to PowerBI and I am trying find a function like Excel's VLOOKUP that will allow me to create a column in Invoice Table 1 that pulls correct margin value from MarginTable2 based on the ID and the time frame of the invoice instance. I need a function not a join please!

 

Table 1: Invoice_Table

invoice_numberIDstart_date   end_date Created_Field_Margin(Margin_Table)
5456110/20/202311/20/2023 
511521/19/20242/19/2024 
1515633/25/20244/26/2024 
515541/18/20242/22/2024 
46565511/20/202312/10/2024 

 

Table 2: Margin_Table

IDstart_dateend_dateMargin
110/20/20231/10/20240.32
210/21/20231/11/20240.55
310/22/20231/12/20240.11
410/23/20231/13/20240.55
510/30/20231/14/20240.57
11/11/20245/21/20240.35
21/12/20245/22/20240.62
31/13/20245/23/20240.16
41/14/20245/24/20240.54
51/15/20245/25/20240.58

 

Desired Output:

This created Margin field would pull the Margin value from the Margin_Table based on the 'ID' and where the invoice falls within start_date and end_date

invoice_numberIDstart_dateend_datecreated_field_margin(Margin_Table)
5456110/20/202311/20/20230.32
511521/19/20242/19/20240.62
1515633/25/20244/26/20240.16
515541/18/20242/22/20240.54
46565511/20/202312/10/20240.57
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @NotVeryGoodatBI ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create a calculated column.

created_field_margin =
CALCULATE (
    SUM ( 'Margin_Table'[Margin] ),
    FILTER (
        'Margin_Table',
        [ID] = EARLIER ( 'Invoice_Table'[ID] )
            && [start_date] <= EARLIER ( 'Invoice_Table'[start_date] )
            && [end_date] >= EARLIER ( 'Invoice_Table'[end_date] )
    )
)

(3) Then the result is as follows.

vtangjiemsft_0-1706600442760.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

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

4 REPLIES 4
Anonymous
Not applicable

Hi @NotVeryGoodatBI ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create a calculated column.

created_field_margin =
CALCULATE (
    SUM ( 'Margin_Table'[Margin] ),
    FILTER (
        'Margin_Table',
        [ID] = EARLIER ( 'Invoice_Table'[ID] )
            && [start_date] <= EARLIER ( 'Invoice_Table'[start_date] )
            && [end_date] >= EARLIER ( 'Invoice_Table'[end_date] )
    )
)

(3) Then the result is as follows.

vtangjiemsft_0-1706600442760.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

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

talespin
Solution Sage
Solution Sage

hi @NotVeryGoodatBI ,

 

Please check LOOKUPVALUE function.

Hi @talespin,

I know I need LOOKUPVALUE, I just need help writing the correct syntax to take into account multiple filters. I need to pull the correct margin for each invoice from the margin table where the IDs match and the invoice timeframe is within the margin timeframe.

.

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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