The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.
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?
Any help will be highly appreciated. Thanks a lot!
Solved! Go to Solution.
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
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,
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,
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