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
D3K
Advocate II
Advocate II

Calculated column with variable periods

Hey everyone!

Faced to the next problem, hope to get a help here.

Here is the question.

I have 2 tables:

- sales

- supplies

As you can see on the picture, product "111" arrives to the store with different intervals and always with different cost prices.

But it sells every day. 

So, how to make such calculated column in the table Sales, which would show the actual cost price of the particular product for the every period from and until the moments of the every cost price have been changed?

2020-01-30_14-40-50 (2).png

 

Any help will be highly appreciated. Thanks a lot!

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

create a new column in supplies


supply end Date = minx(filter(supplies,supplies[product id]=earlier(supplies[product id]) && supplies[Supply Date]> earlier(supplies[Supply Date])),supplies[Supply Date])

 

create a new column in sales

cost = minx(filter(sales,sales[sales_date]>=supplies[Supply Date]
&& (isbalnk(supplies[supply end Date]) || sales[sales_date] <supplies[supply end Date])),supplies[cost for 1 pc])

 

Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution. In case it does not help, please provide additional information and mark me with @
Thanks. My Recent Blog -
Winner-Topper-on-Map-How-to-Color-States-on-a-Map-with-Winners , HR-Analytics-Active-Employee-Hire-and-Termination-trend
Power-BI-Working-with-Non-Standard-Time-Periods And Comparing-Data-Across-Date-Ranges

Connect on Linkedin

View solution in original post

v-lid-msft
Community Support
Community Support

Hi @D3K ,

 

We can also create a  calculated column in Sales Table to meet you requeriement:

 

 

Cost Price for 1 pc =
VAR i = [Product ID]
VAR d = [Sales Date]
RETURN
    CALCULATE (
        SUM ( 'Supplies'[Cost price for 1 pc] ),
        FILTER (
            'Supplies',
            'Supplies'[Product ID] = i
                && 'Supplies'[Supply Date]
                    = CALCULATE (
                        MAX ( 'Supplies'[Supply Date] ),
                        FILTER (
                            'Supplies',
                            'Supplies'[Product ID] = i
                                && 'Supplies'[Supply Date] <= d
                        )
                    )
        )
    )

 


Best regards,

 

Community Support Team _ Dong Li
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
D3K
Advocate II
Advocate II

Thank you @v-lid-msft  and @amitchandak 

Both ways are working perfect!

v-lid-msft
Community Support
Community Support

Hi @D3K ,

 

We can also create a  calculated column in Sales Table to meet you requeriement:

 

 

Cost Price for 1 pc =
VAR i = [Product ID]
VAR d = [Sales Date]
RETURN
    CALCULATE (
        SUM ( 'Supplies'[Cost price for 1 pc] ),
        FILTER (
            'Supplies',
            'Supplies'[Product ID] = i
                && 'Supplies'[Supply Date]
                    = CALCULATE (
                        MAX ( 'Supplies'[Supply Date] ),
                        FILTER (
                            'Supplies',
                            'Supplies'[Product ID] = i
                                && 'Supplies'[Supply Date] <= d
                        )
                    )
        )
    )

 


Best regards,

 

Community Support Team _ Dong Li
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

create a new column in supplies


supply end Date = minx(filter(supplies,supplies[product id]=earlier(supplies[product id]) && supplies[Supply Date]> earlier(supplies[Supply Date])),supplies[Supply Date])

 

create a new column in sales

cost = minx(filter(sales,sales[sales_date]>=supplies[Supply Date]
&& (isbalnk(supplies[supply end Date]) || sales[sales_date] <supplies[supply end Date])),supplies[cost for 1 pc])

 

Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution. In case it does not help, please provide additional information and mark me with @
Thanks. My Recent Blog -
Winner-Topper-on-Map-How-to-Color-States-on-a-Map-with-Winners , HR-Analytics-Active-Employee-Hire-and-Termination-trend
Power-BI-Working-with-Non-Standard-Time-Periods And Comparing-Data-Across-Date-Ranges

Connect on Linkedin

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.