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

How to calculate the cost of a product using different formulas depending of the month&year?

Hi everyone,

 

Happy holidays!

I need to show the evolution of the cost of products and I have the following datasets:

 

  • Number 1: Product / Ingredient / % of ingredient in the product / Month&Year of formula update. Example:
ProductIngredient% of ingredient in the productMonth&Year of formula update
A

A1

0.503/2021
AA20.503/2021
AA10.606/2022
AA30.406/2022

 

  • Number 2: Ingredients / Year&Month of cost / Cost. Example:
IngredientsMonth&Year of costCost
A101/2021u
A102/2021v
A103/2021x
.........

 

I need to create a table which shows me:

  • Product / Ingredient / % of ingredient in the product * Cost / Year&Month of cost

By taking the correct Ingredient, % of ingredient in the product and Cost, depending on the relationship between Month&Year of formula update and the Month&Year of cost. Example:

 

ProductIngredient% of ingredient in the product * CostMonth&Year of cost
A

A1

0.5 * xAll "Year&Month of cost" after 03/2021 and before 06/2022
AA20.5 * yAll "Year&Month of cost" after 03/2021 and before 06/2022
AA10.6 * wAll "Year&Month of cost" after 06/2022
AA30.4 * z

All "Year&Month of cost" after 06/2022

 

I was thinking about merging table Number 1 with table Number 2, but I don't know how to tell PowerBI to implement the right logic for which products formulas to use depending on the dates...

 

Any thoughts?

 

Thanks!

 

1 ACCEPTED SOLUTION
v-binbinyu-msft
Community Support
Community Support

Hi @mridz ,

Please try below steps:

1. below is my test table

Table1:

vbinbinyumsft_0-1672642912091.png

Table2:

vbinbinyumsft_1-1672642928494.png

2. create a measure with below dax formula

Measure =
VAR cur_ingre =
    SELECTEDVALUE ( Table1[% of ingredient in the product] )
VAR cur_it =
    SELECTEDVALUE ( Table1[Ingredient] )
VAR cur_ym =
    SELECTEDVALUE ( Table1[Month&Year of formula update] )
VAR tmp =
    FILTER (
        ALL ( 'Table 2' ),
        'Table 2'[Ingredients] = cur_it
            && 'Table 2'[Month&Year of cost] >= cur_ym
    )
VAR _date =
    MINX ( tmp, [Month&Year of cost] )
VAR _val =
    CALCULATE (
        MAX ( 'Table 2'[Cost] ),
        'Table 2'[Ingredients] = cur_it,
        'Table 2'[Month&Year of cost] = _date
    )
RETURN
    cur_ingre & " * " & _val

3. add a table visual with Table1 fields and measure

vbinbinyumsft_2-1672643022323.png

Please refer the attached .pbix file.

 

Best regards,
Community Support Team_Binbin Yu
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

3 REPLIES 3
v-binbinyu-msft
Community Support
Community Support

Hi @mridz ,

Please try below steps:

1. below is my test table

Table1:

vbinbinyumsft_0-1672642912091.png

Table2:

vbinbinyumsft_1-1672642928494.png

2. create a measure with below dax formula

Measure =
VAR cur_ingre =
    SELECTEDVALUE ( Table1[% of ingredient in the product] )
VAR cur_it =
    SELECTEDVALUE ( Table1[Ingredient] )
VAR cur_ym =
    SELECTEDVALUE ( Table1[Month&Year of formula update] )
VAR tmp =
    FILTER (
        ALL ( 'Table 2' ),
        'Table 2'[Ingredients] = cur_it
            && 'Table 2'[Month&Year of cost] >= cur_ym
    )
VAR _date =
    MINX ( tmp, [Month&Year of cost] )
VAR _val =
    CALCULATE (
        MAX ( 'Table 2'[Cost] ),
        'Table 2'[Ingredients] = cur_it,
        'Table 2'[Month&Year of cost] = _date
    )
RETURN
    cur_ingre & " * " & _val

3. add a table visual with Table1 fields and measure

vbinbinyumsft_2-1672643022323.png

Please refer the attached .pbix file.

 

Best regards,
Community Support Team_Binbin Yu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@mridz , You can check to merge in power query, and you can select multiple column to join

Merge Tables (Power Query) : https://www.youtube.com/watch?v=zNrmbagO0Oo&list=PLPaNVDMhUXGaaqV92SBD5X2hk3TMNlHhb&index=16

 

or copy columns in DAX

refer 4 ways (related, relatedtable, lookupvalue, sumx/minx/maxx with filter) to copy data from one table to another
https://www.youtube.com/watch?v=Wu1mWxR23jU
https://www.youtube.com/watch?v=czNHt7UXIe8

 

or DAX joins

https://www.sqlbi.com/articles/from-sql-to-dax-joining-tables/

Thanks @amitchandak. My difficulty is on knowing which expression to use to get the right ingredients and % of ingredient in the product depending on the dates...

 

 

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.