March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi there,
I'm just starting with Power BI and can't figure out the following.
I have a daycount colomn and a costs colomn. I want to device costs by total daycount. After that I want to multiply 'costs per daycount' times daycount. In the snip below the result for the top row should be 236.30 (375/146* 92)and the botom row 138.70.
I calculated daycount: Daycount = DATEDIFF(MIN([Start Date];[Einddatum]);MAX([start Date];[Einddatum]);DAY)
Costs 2018 is a colomn in anonther query.
Solved! Go to Solution.
Hi @JBikker,
Here we can take the following steps to meet your requirement.
1. Add a calculated column to get the sum of Daycount per contract.
Sum = CALCULATE(SUM(Subscriptions[Daycount]),FILTER(ALL(Subscriptions),Subscriptions[Part of contract]=EARLIER(Subscriptions[Part of contract])))
2. Then can need to update the formula as below.
Result = RELATED(Contracts[Costs 2018]) / Subscriptions[Sum] * Subscriptions[Daycount]
For more details, please check the pbix as attached.
https://www.dropbox.com/s/ofd8q15osojrozr/prev2.pbix?dl=0
Regards,
Frank
Hi @JBikker,
As your description, I made a sample here. As you said Costs 2018 is a column in another query. To achieve your goal here, the two tables should be related. So I created relationship between the DATA and cost tables based on index columns in advance.
Then we can create the calculate column in Data table using the formula.
Result = RELATED(Cost[Cost 2018])/SUM(DATA[Daycount])*DATA[Daycount]
Then we can get the result as we excepted.
For more details, please check the pbix as attached. If this doesn’t meet your requirement, kindly share you sample data to me please.
https://www.dropbox.com/s/401oxqjtl2uq4jv/Costsdaycount2.pbix?dl=0
Regards,
Frank
@v-frfei-msftThanks so much for your help! I'm getting closer. I have two followup questions.
1. How can you calculate daycount if there is no enddate yet? If the enddate is blank I would like to get the result Startdate > Today
2. 'Price' is not always the same. Subscriptions are part of different contract. When I used your method in my model it did not filter per contract but instead summed up all 'daycount's from different contracts.
I've attached a file.. Hopefully this makes it a bit more clear. The column result does not make any sense.
Hi @JBikker,
Here we can take the following steps to meet your requirement.
1. Add a calculated column to get the sum of Daycount per contract.
Sum = CALCULATE(SUM(Subscriptions[Daycount]),FILTER(ALL(Subscriptions),Subscriptions[Part of contract]=EARLIER(Subscriptions[Part of contract])))
2. Then can need to update the formula as below.
Result = RELATED(Contracts[Costs 2018]) / Subscriptions[Sum] * Subscriptions[Daycount]
For more details, please check the pbix as attached.
https://www.dropbox.com/s/ofd8q15osojrozr/prev2.pbix?dl=0
Regards,
Frank
Hi @JBikker,
Does that make sense? If so, kindly mark my answer as a solution to close the case please.
Regards,
Frank
Hi Frank, Yes it does make sense. Thanks so much! I tried to close it a couple of times now but I keep getting the following error. I tried different browser but I keep getting the error... JavaScript is on...
Authentication failed for the action you are trying to do. This failure could be due to your browser not supporting JavaScript, JavaScript not being enabled, or trying to use the action URL directly in the browser address bar instead of clicking the link on the page.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
User | Count |
---|---|
90 | |
89 | |
85 | |
73 | |
49 |
User | Count |
---|---|
167 | |
147 | |
92 | |
70 | |
58 |