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
SGBaringa
Regular Visitor

Extracting number based on range of dates

Hello PBI Community!

 

Hope you can help me out on this. 

 

I have 2 tables:

  • TableA
IDDateDemand
11-Apr-20241000
21-May-20242000
  • TableB
IDFromToPrice
11-Jan-20241-Feb-202420
21-May-20241-Jun-202430
11-Mar-20241-Jun-202430

 

What I am trying to achieve is to map the IDs from the two tables and also if the Date from TableA aligns with the period from TableB to multiply the Demand with the Price.

 

For example, the price from Mar-2024 to Jun-2024 for ID 1 is 30 and the Demand for May 2024 is 2000, so it would be 60000.

 

Thank you!

2 ACCEPTED SOLUTIONS
Greg_Deckler
Super User
Super User

@SGBaringa LOOKUPVALUE Range - Microsoft Fabric Community


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

v-huijiey-msft
Community Support
Community Support

Hi @SGBaringa ,

 

Thanks for the reply from @Greg_Deckler .

 

Merge the two tables in Power Query and select Full Outer for the join method.

vhuijieymsft_0-1714026386342.png
vhuijieymsft_1-1714026386345.png

 

Expand TableB.

vhuijieymsft_2-1714026405887.png

 

The cleaned data is shown below.

vhuijieymsft_3-1714026405888.png

 

Create a measure:

Measure = 
IF (
    MAX ( 'TableA'[Date] ) >= MAX ( 'Merge1'[From] )
        && MAX ( 'TableA'[Date] ) <= MAX ( 'Merge1'[To] ),
    MAX ( 'Merge1'[Price] ) * MAX ( 'Merge1'[Demand] ),
    BLANK ()
)

vhuijieymsft_4-1714026444745.png

 

For example, the price from Mar-2024 to Jun-2024 for ID 1 is 30 and the Demand for April 2024 is 1000, so it would be 30000, the price from May-2024 to Jun-2024 for ID 2 is 30 and the Demand for April 2024 is 2000, so it would be 60000.

 

The pbix file is attached.

 

If you have any other questions please feel free to contact me.

 

Best Regards,
Yang
Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

View solution in original post

2 REPLIES 2
v-huijiey-msft
Community Support
Community Support

Hi @SGBaringa ,

 

Thanks for the reply from @Greg_Deckler .

 

Merge the two tables in Power Query and select Full Outer for the join method.

vhuijieymsft_0-1714026386342.png
vhuijieymsft_1-1714026386345.png

 

Expand TableB.

vhuijieymsft_2-1714026405887.png

 

The cleaned data is shown below.

vhuijieymsft_3-1714026405888.png

 

Create a measure:

Measure = 
IF (
    MAX ( 'TableA'[Date] ) >= MAX ( 'Merge1'[From] )
        && MAX ( 'TableA'[Date] ) <= MAX ( 'Merge1'[To] ),
    MAX ( 'Merge1'[Price] ) * MAX ( 'Merge1'[Demand] ),
    BLANK ()
)

vhuijieymsft_4-1714026444745.png

 

For example, the price from Mar-2024 to Jun-2024 for ID 1 is 30 and the Demand for April 2024 is 1000, so it would be 30000, the price from May-2024 to Jun-2024 for ID 2 is 30 and the Demand for April 2024 is 2000, so it would be 60000.

 

The pbix file is attached.

 

If you have any other questions please feel free to contact me.

 

Best Regards,
Yang
Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

Greg_Deckler
Super User
Super User

@SGBaringa LOOKUPVALUE Range - Microsoft Fabric Community


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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.