Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hi
I am trying to get the calculated value based on these relationships:
Project Initiation Phase - M02
Scope and Feasibility - M04
Design Phase - M12
Delivery Phase - M23
Handover/Takeover - M24
Project Close - M 25
Sample data on different projects with the required calculated values is as shown:
ProjectName | ObjectName | ForecastFinishDate | ActualFinishDate | Calculated value |
1000 | Delivery Phase | 20/05/2020 | 27/08/2020 | 30/04/2020 |
1000 | Design Phase | 14/06/2019 | 11/06/2019 | 28/05/2019 |
1000 | Hand Over/Take Over Phase | 10/12/2019 | 4/02/2021 | 4/02/2021 |
1000 | M02 | 00/00/0000 | 5/02/2018 | |
1000 | M04 | 00/00/0000 | 12/07/2018 | |
1000 | M12 | 00/00/0000 | 28/05/2019 | |
1000 | M23 | 00/00/0000 | 30/04/2020 | |
1000 | M24 | 00/00/0000 | 4/02/2021 | |
1000 | M25 | 00/00/0000 | 4/02/2021 | |
1000 | Project Close Phase | 10/12/2019 | 00/00/0000 | 4/02/2021 |
1000 | Project Initiation Phase | 23/01/2018 | 5/02/2018 | 5/02/2018 |
1000 | Scope and Feasibility Phase | 28/05/2018 | 12/07/2018 | 12/07/2018 |
2000 | Delivery Phase | 25/11/2019 | 20/11/2019 | 20/11/2019 |
2000 | Design Phase | 10/12/2016 | 6/04/2018 | 6/04/2018 |
2000 | Hand Over/Take Over Phase | 30/09/2019 | 23/07/2020 | 4/08/2020 |
2000 | M02 | 00/00/0000 | 1/06/2015 | |
2000 | M04 | 00/00/0000 | 22/10/2016 | |
2000 | M12 | 00/00/0000 | 6/04/2018 | |
2000 | M23 | 00/00/0000 | 20/11/2019 | |
2000 | M24 | 00/00/0000 | 4/08/2020 | |
2000 | M25 | 00/00/0000 | 00/00/0000 | |
2000 | Project Close Phase | 22/10/2020 | 00/00/0000 | 00/00/0000 |
2000 | Project Initiation Phase | 1/06/2015 | 1/06/2015 | 1/06/2015 |
2000 | Scope and Feasibility Phase | 22/10/2016 | 22/10/2016 | 22/10/2016 |
3000 | … | … | … | … |
3000 | … | … | … | … |
Solved! Go to Solution.
Hi @calvgo
Try this new code to add a column:
Calculated Value =
VAR _A =
SWITCH (
TRUE (),
[ObjectName] = "Project Initiation Phase", "M02 - Approve Fee Proposal",
[ObjectName] = "Scope and Feasibility", "M04 - Approve Phase 1 Report",
[ObjectName] = "Design Phase", "M12 - Approve Phase 2 Report",
[ObjectName] = "Delivery Phase", "M23 - Issue Certificate of Completion",
[ObjectName] = "Hand Over/Take Over Phase", "M24 - Recommend Hand Over Acceptance",
[ObjectName] = "Project Close Phase", "M25 - Reduce PO Values To Zero",
[ObjectName] = "Scope and Feasibility Phase", "Scope and Feasibility Phase",
BLANK ()
)
VAR _B =
IF (
ISBLANK ( _A ),
BLANK (),
CALCULATE (
MAX ( 'Table'[ActualFinishDate] ),
FILTER (
ALL ( 'Table' ),
[ObjectName] = _A
&& [ProjectName] = EARLIER ( 'Table'[ProjectName] )
)
)
)
RETURN
IF (
ISBLANK ( _B ),
CALCULATE (
MAX ( 'Table'[FinishDate] ),
FILTER (
ALL ( 'Table' ),
[ObjectName] = _A
&& [ProjectName] = EARLIER ( 'Table'[ProjectName] )
)
),
_B
)
Output:
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: www.linkedin.com/in/vahid-dm/
Hi @calvgo
Can you post sample data as text and expected output?
Not enough information to go on, and it's not clear for me!
please see this post regarding How to Get Your Question Answered Quickly:
https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490
Appreciate your Kudos!!
LinkedIn:www.linkedin.com/in/vahid-dm/
ProjectName | ObjectName | ForecastFinishDate | ActualFinishDate | Calculated value |
1000 | Delivery Phase | 20/05/2020 | 27/08/2020 | 30/04/2020 |
1000 | Design Phase | 14/06/2019 | 11/06/2019 | 28/05/2019 |
1000 | Hand Over/Take Over Phase | 10/12/2019 | 4/02/2021 | 4/02/2021 |
1000 | M02 | 00/00/0000 | 5/02/2018 | |
1000 | M04 | 00/00/0000 | 12/07/2018 | |
1000 | M12 | 00/00/0000 | 28/05/2019 | |
1000 | M23 | 00/00/0000 | 30/04/2020 | |
1000 | M24 | 00/00/0000 | 4/02/2021 | |
1000 | M25 | 00/00/0000 | 4/02/2021 | |
1000 | Project Close Phase | 10/12/2019 | 00/00/0000 | 4/02/2021 |
1000 | Project Initiation Phase | 23/01/2018 | 5/02/2018 | 5/02/2018 |
1000 | Scope and Feasibility Phase | 28/05/2018 | 12/07/2018 | 12/07/2018 |
2000 | Delivery Phase | 25/11/2019 | 20/11/2019 | 20/11/2019 |
2000 | Design Phase | 10/12/2016 | 6/04/2018 | 6/04/2018 |
2000 | Hand Over/Take Over Phase | 30/09/2019 | 23/07/2020 | 4/08/2020 |
2000 | M02 | 00/00/0000 | 1/06/2015 | |
2000 | M04 | 00/00/0000 | 22/10/2016 | |
2000 | M12 | 00/00/0000 | 6/04/2018 | |
2000 | M23 | 00/00/0000 | 20/11/2019 | |
2000 | M24 | 00/00/0000 | 4/08/2020 | |
2000 | M25 | 00/00/0000 | 00/00/0000 | |
2000 | Project Close Phase | 22/10/2020 | 00/00/0000 | 00/00/0000 |
2000 | Project Initiation Phase | 1/06/2015 | 1/06/2015 | 1/06/2015 |
2000 | Scope and Feasibility Phase | 22/10/2016 | 22/10/2016 | 22/10/2016 |
3000 | … | … | … | … |
3000 | … | … | … | … |
Essentially, I am trying to get the actual finish date from all the M labels i.e. M02, M04, M23 etc into the various phases. One example would be getting the M02 -actual finished into the project initation phase for project name 1000- so it would be 05/02/2018 as the newly calculated field in Project Initiation Phase.
Hope this is clear.
Hi @calvgo
Try this code to add a new column to your table:
Calculated Value =
VAR _A =
SWITCH (
TRUE (),
[ObjectName] = "Project Initiation Phase", "M02",
[ObjectName] = "Scope and Feasibility", "M04",
[ObjectName] = "Design Phase", "M12",
[ObjectName] = "Delivery Phase", "M23",
[ObjectName] = "Hand Over/Take Over Phase", "M24",
[ObjectName] = "Project Close Phase", "M25",
[ObjectName] = "Scope and Feasibility Phase", "Scope and Feasibility Phase",
BLANK ()
)
RETURN
IF (
ISBLANK ( _A ),
BLANK (),
CALCULATE (
MAX ( 'Table'[ActualFinishDate] ),
FILTER (
ALL ( 'Table' ),
[ObjectName] = _A
&& [ProjectName] = EARLIER ( 'Table'[ProjectName] )
)
)
)
Output:
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: www.linkedin.com/in/vahid-dm/
Thanks Vahid-that was great!
However, I was testing the data and had another issue you might be able to help. Sometimes, the data will come up with 00/00/0000 for the actual finish and then I have to search for another finish date field. In this example, when project close for project name = 2000, the value is 00/00/0000, so I will have to use another date field (column 5) in M25.. so the calculated field should become 11/10/2021 instead of 00/00/0000 for project 2000 during project close.
Hope this is clear.
ProjectName | ObjectName | ForecastFinishDate | ActualFinishDate | FinishDate | Calculated |
1000 | Delivery Phase | 20/05/2020 | 27/08/2020 | 30.04.2020 | 30/04/2020 |
1000 | Design Phase | 14/06/2019 | 11/06/2019 | 11.06.2019 | 28/05/2019 |
1000 | Hand Over/Take Over Phase | 10/12/2019 | 4/02/2021 | 24.02.2021 | 4/02/2021 |
1000 | M02 - Approve Fee Proposal | 00/00/0000 | 5/02/2018 | 05.02.2018 | |
1000 | M04 - Approve Phase 1 Report | 00/00/0000 | 12/07/2018 | 12.07.2018 | |
1000 | M12 - Approve Phase 2 Report | 00/00/0000 | 28/05/2019 | 11.06.2019 | |
1000 | M23 - Issue Certificate of Completion | 00/00/0000 | 30/04/2020 | 30.04.2020 | |
1000 | M24 - Recommend Hand Over Acceptance | 00/00/0000 | 4/02/2021 | 24.02.2021 | |
1000 | M25 - Reduce PO Values To Zero | 00/00/0000 | 4/02/2021 | 11.03.2021 | |
1000 | Project Close Phase | 10/12/2019 | 00/00/0000 | 30.04.2021 | 4/02/2021 |
1000 | Project Initiation Phase | 23/01/2018 | 5/02/2018 | 05.02.2018 | 5/02/2018 |
1000 | Scope and Feasibility Phase | 28/05/2018 | 12/07/2018 | 12.07.2018 | 12/07/2018 |
2000 | Delivery Phase | 25/11/2019 | 20/11/2019 | 20.11.2019 | 20/11/2019 |
2000 | Design Phase | 10/12/2016 | 6/04/2018 | 06.04.2018 | 6/04/2018 |
2000 | Hand Over/Take Over Phase | 30/09/2019 | 23/07/2020 | 21.02.2020 | 4/08/2020 |
2000 | M02 - Approve Fee Proposal | 00/00/0000 | 1/06/2015 | 01.06.2015 | |
2000 | M04 - Approve Phase 1 Report | 00/00/0000 | 22/10/2016 | 24.10.2016 | |
2000 | M12 - Approve Phase 2 Report | 00/00/0000 | 6/04/2018 | 06.04.2018 | |
2000 | M23 - Issue Certificate of Completion | 00/00/0000 | 20/11/2019 | 20.11.2019 | |
2000 | M24 - Recommend Hand Over Acceptance | 00/00/0000 | 4/08/2020 | 21.02.2020 | |
2000 | M25 - Reduce PO Values To Zero | 00/00/0000 | 00/00/0000 | 11.10.2021 | |
2000 | Project Close Phase | 22/10/2020 | 00/00/0000 | 19.02.2021 | 00/00/0000 |
2000 | Project Initiation Phase | 1/06/2015 | 1/06/2015 | 01.06.2015 | 1/06/2015 |
2000 | Scope and Feasibility Phase | 22/10/2016 | 22/10/2016 | 24.10.2016 | 22/10/2016 |
3000 | … | … | … | … | |
3000 | … | … | … | … |
How did you find that 11/10/2021 instead of 00/00/0000 for project close project 2000? there is no date like that in your table?
can you add more details?
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: www.linkedin.com/in/vahid-dm/
Hi Vahid,
See this updated dataset-realised that it wasn't updated properly previously. I need to use the 5th column data (See the orange in M25 in particular) for the calculated field.
ProjectName | ObjectName | ForecastFinishDate | ActualFinishDate | FinishDate | Calculated |
1000 | Delivery Phase | 20/05/2020 | 27/08/2020 | 30.04.2020 | 30/04/2020 |
1000 | Design Phase | 14/06/2019 | 11/06/2019 | 11.06.2019 | 28/05/2019 |
1000 | Hand Over/Take Over Phase | 10/12/2019 | 4/02/2021 | 24.02.2021 | 4/02/2021 |
1000 | M02 - Approve Fee Proposal | 00/00/0000 | 5/02/2018 | 05.02.2018 | |
1000 | M04 - Approve Phase 1 Report | 00/00/0000 | 12/07/2018 | 12.07.2018 | |
1000 | M12 - Approve Phase 2 Report | 00/00/0000 | 28/05/2019 | 11.06.2019 | |
1000 | M23 - Issue Certificate of Completion | 00/00/0000 | 30/04/2020 | 30.04.2020 | |
1000 | M24 - Recommend Hand Over Acceptance | 00/00/0000 | 4/02/2021 | 24.02.2021 | |
1000 | M25 - Reduce PO Values To Zero | 00/00/0000 | 4/02/2021 | 11.03.2021 | |
1000 | Project Close Phase | 10/12/2019 | 00/00/0000 | 30.04.2021 | 4/02/2021 |
1000 | Project Initiation Phase | 23/01/2018 | 5/02/2018 | 05.02.2018 | 5/02/2018 |
1000 | Scope and Feasibility Phase | 28/05/2018 | 12/07/2018 | 12.07.2018 | 12/07/2018 |
2000 | Delivery Phase | 25/11/2019 | 20/11/2019 | 20.11.2019 | 20/11/2019 |
2000 | Design Phase | 10/12/2016 | 6/04/2018 | 06.04.2018 | 6/04/2018 |
2000 | Hand Over/Take Over Phase | 30/09/2019 | 23/07/2020 | 21.02.2020 | 4/08/2020 |
2000 | M02 - Approve Fee Proposal | 00/00/0000 | 1/06/2015 | 01.06.2015 | |
2000 | M04 - Approve Phase 1 Report | 00/00/0000 | 22/10/2016 | 24.10.2016 | |
2000 | M12 - Approve Phase 2 Report | 00/00/0000 | 6/04/2018 | 06.04.2018 | |
2000 | M23 - Issue Certificate of Completion | 00/00/0000 | 20/11/2019 | 20.11.2019 | |
2000 | M24 - Recommend Hand Over Acceptance | 00/00/0000 | 4/08/2020 | 21.02.2020 | |
2000 | M25 - Reduce PO Values To Zero | 00/00/0000 | 00/00/0000 | 11.10.2021 | |
2000 | Project Close Phase | 22/10/2020 | 00/00/0000 | 19.02.2021 | 11/10/2021 |
2000 | Project Initiation Phase | 1/06/2015 | 1/06/2015 | 01.06.2015 | 1/06/2015 |
2000 | Scope and Feasibility Phase | 22/10/2016 | 22/10/2016 | 24.10.2016 | 22/10/2016 |
3000 | … | … | … | … | |
3000 | … | … | … | … |
Hi Vahid,
Can you see the updated dataset I have provided you above?
See this particular row in the dataset.
2000 | M25 - Reduce PO Values To Zero | 00/00/0000 | 00/00/0000 | 11.10.2021 |
Hi @calvgo
Try this new code to add a column:
Calculated Value =
VAR _A =
SWITCH (
TRUE (),
[ObjectName] = "Project Initiation Phase", "M02 - Approve Fee Proposal",
[ObjectName] = "Scope and Feasibility", "M04 - Approve Phase 1 Report",
[ObjectName] = "Design Phase", "M12 - Approve Phase 2 Report",
[ObjectName] = "Delivery Phase", "M23 - Issue Certificate of Completion",
[ObjectName] = "Hand Over/Take Over Phase", "M24 - Recommend Hand Over Acceptance",
[ObjectName] = "Project Close Phase", "M25 - Reduce PO Values To Zero",
[ObjectName] = "Scope and Feasibility Phase", "Scope and Feasibility Phase",
BLANK ()
)
VAR _B =
IF (
ISBLANK ( _A ),
BLANK (),
CALCULATE (
MAX ( 'Table'[ActualFinishDate] ),
FILTER (
ALL ( 'Table' ),
[ObjectName] = _A
&& [ProjectName] = EARLIER ( 'Table'[ProjectName] )
)
)
)
RETURN
IF (
ISBLANK ( _B ),
CALCULATE (
MAX ( 'Table'[FinishDate] ),
FILTER (
ALL ( 'Table' ),
[ObjectName] = _A
&& [ProjectName] = EARLIER ( 'Table'[ProjectName] )
)
),
_B
)
Output:
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: www.linkedin.com/in/vahid-dm/
Thanks Vahid-that was brilliant scripting that helped a lot! 🙂
No Worries 🙏
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
9 | |
8 | |
8 | |
8 |
User | Count |
---|---|
13 | |
12 | |
11 | |
10 | |
8 |