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
spandiar
Frequent Visitor

Help required-Value from another table on the bases effective date

Hi,

 

I have 2 tables, they are both join with product( many to many relationship).

Order 
Order NoOrderdateProduct 
101/01/2021A
202/01/2021B
301/02/2021A
402/02/2021B
502/02/2021A
603/02/2021B
725/02/2021A
826/02/2021A
907/02/2021B
1008/03/2021A
   

 

Cost  
Cost %EffectiveDateProduct
1.101/01/2021A
1.401/01/2021B
1.501/02/2021A
1.815/02/2021A
1.901/03/2021A
202/02/2021B
   

Need the result like this 

Order   
Order NoOrderdateProduct Cost%
101/01/2021A1.1
202/01/2021B1.4
301/02/2021A1.1
402/02/2021B2
502/02/2021A1.5
603/02/2021B2
725/02/2021A1.8
826/02/2021A1.8
907/02/2021B1.5
1008/03/2021A1.9

 

If write custom colum to get cost% in order table this its give error of multiple values

VCost% =LOOKUPVALUE('Product'[Cost%],'Product'[Product],'Order'[Product])
 
Or 
no result
Vcost% =CALCULATE(SELECTEDVALUE(Product[Cost%]),Orderdate>=MINX(Product,Product[EfffectiveDate])&& OrderDate <=MAXX(Product,Product[EffectiveDate]))
 OR
 I have tried this also but no result

Cost1% =
Var MinEffDate = CALCULATE(MINX('Cost','Cost'[EffectiveDate]),FILTER('Cost','Cost'[Product]=('Order'[Product])))
Var MaxEffDate = CALCULATE(MAXX('Cost','Cost'[EffectiveDate]),FILTER('Cost','Cost'[Product]=('Order'[Product])))
Return
CALCULATE(SELECTEDVALUE('Cost'[Cost%]),'Order'[Orderdate]>=MinEffDate &&'Order'[Orderdate] <=MaxEffDate,FILTER('Cost','Cost'[Product]=('Order'[Product])))
 
Can you please how can I achieve this result.
Thanks
 
 
1 ACCEPTED SOLUTION

Hi @spandiar ,

 

Try this code to create a calcualted column.

Cost % = 
VAR _MAXDATE_BEFORE =
    CALCULATE (
        MAX ( Cost[EffectiveDate] ),
        FILTER (
            Cost,
            AND (
                Cost[Product] = EARLIER ( 'Order'[Product ] ),
                Cost[EffectiveDate] <= EARLIER ( 'Order'[Orderdate] )
            )
        )
    )
VAR _COST =
    CALCULATE (
        SUM ( Cost[Cost %] ),
        FILTER (
            Cost,
            AND (
                Cost[Product] = EARLIER ( 'Order'[Product ] ),
                Cost[EffectiveDate] = _MAXDATE_BEFORE
            )
        )
    )
RETURN
    _COST

Result is as below.

1.png

You can download my sample file as below to learn more details.

 

Best Regards,
Rico Zhou

 

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
Greg_Deckler
Super User
Super User

@spandiar So my normal go to for an alternative to LOOKUPVALUE is simply MAXX(FILTER(...),...)


@ 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...

If I write following code then its gives circular dependency error 
Vcost% =CALCULATE(SELECTEDVALUE(Product[Cost%]),Orderdate>=MINX(Product,Product[EfffectiveDate])&& OrderDate <=MAXX(Product,Product[EffectiveDate]))

Hi @spandiar ,

 

Try this code to create a calcualted column.

Cost % = 
VAR _MAXDATE_BEFORE =
    CALCULATE (
        MAX ( Cost[EffectiveDate] ),
        FILTER (
            Cost,
            AND (
                Cost[Product] = EARLIER ( 'Order'[Product ] ),
                Cost[EffectiveDate] <= EARLIER ( 'Order'[Orderdate] )
            )
        )
    )
VAR _COST =
    CALCULATE (
        SUM ( Cost[Cost %] ),
        FILTER (
            Cost,
            AND (
                Cost[Product] = EARLIER ( 'Order'[Product ] ),
                Cost[EffectiveDate] = _MAXDATE_BEFORE
            )
        )
    )
RETURN
    _COST

Result is as below.

1.png

You can download my sample file as below to learn more details.

 

Best Regards,
Rico Zhou

 

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

Thanks for the solution, it worked perfectly. 

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