fbpx
Search
Close this search box.

Calculating Critical Path using Excel Formulas [Project Management]

Share

Facebook
Twitter
LinkedIn

Do you know that we can easily calculate the critical path for a project using Excel formulas?

For a long time, it has been tricky to calculate the Critical Path using Excel formulas. But thanks to the arrival of new Dynamic Array functionality in Excel, we can now calculate critical path. In this article let me describe the approach with an example.

Put on your hardhats, this one is going to blow your minds.

What is Critical Path Method (CPM)?

Critical Path Method gives us a framework to analyze and optimize a project plan. Let’s say you have a project with 6 activities, as depicted below. Then we can find a critical path that determines the total duration of the project using Critical Path Method.

The critical path is the longest sequence of tasks that must be completed to execute a project. The tasks on the critical path are called critical activities because if they’re delayed, the whole project completion will be delayed.

How do you calculate the Critical Path?

To calculate the critical path, you need below details about the project plan:

  • Complete list of all planned activities
  • Estimated duration for all activities (t)
  • Dependencies for each activity 

In many real-world scenarios, accurately listing all three of them is impossible. And that is why CPM technique is often criticized.

Once you have all of them, we need to apply critical path algorithm to calculate below 5 values.

  • Earliest Starting time (ES): This is maximum Earliest Finish (EF) of all predecessors of an activity. 
  • Earliest Finish time (EF): This is ES + duration of the activity (t)
  • Latest Finish time (LF): This is the minimum Latest Start time (LS) of all successors of an activity. 
  • Latest Starting time (LS): This is LF – duration of the activity (t)
  • Float or Slack (F): This is the gap between Latest Start (LS) and Earliest Start (ES). For activities on critical path this value would be 0.

 

Learn more about Critical Path Method:

Critical Path Calculations with an Example

Let’s go back to our 6 activity project. We can assign durations for each activity like this:

project plan (critical path analysis with Excel)

We can use below notation when capturing this data in Excel table.

Excel table format for critical path input data

Calculating ES, EF, LS, LF & Float with Formulas

Adjacent to the input data table, add 6 columns for all our calculations. Our table should look like this:

CPM Calculations in Excel - table format

Now, lets understand the formulas for Successors, Early Start (ES), Early Finish (EF), Latest Start (LS) and Latest Finish (LF).

Early Start Formula (ES)

Early Start is the earliest an activity can begin. An activity can only start when all of its predecessors have finished. So this is same as the maximum of Early Finish (EF) for all the predecessors. If an activity has no predecessors, then it can start right away.

As we have the list of predecessors in the cell [@Predecessors], we can loop thru them and find the maximum finish time for them.

Here is the formula I used.

				
					=IF([@Predecessors]="",0, MAX(CHOOSEROWS([EF],TEXTSPLIT([@Predecessors],",")+0)))
				
			

For activities without predecessors, we set the value of ES as 0.

For all other activities, we split the [@Predecessors] by comma (using TEXTSPLIT) and convert these text values to numbers (by adding a 0 to them). We then pick the maximum of all these activity’s earliest finish time [EF] using MAX & CHOOSEROWS functions.

Early Finish Formula (EF)

This is easy. We just add duration to early start (ES).

				
					=[@ES]+[@[Estimated Duration]]
				
			

🤔Did you notice the circular nature of these formulas?

Even though ES formula depends on EF and EF formula depends on ES (head hurts, innit?), you need not worry. Excel will calculate both of these values fine as long as there are no loops  in your project data (ie. Activity 1 depends on 2 and 2 depends on 1)

Successors Formula

Before we calculate the Latest Start (LS) and Latest Finish (LF) times, it is a good idea to calculate the list of successors for each activity. 

I used this formula for that:

				
					=TEXTJOIN(",",TRUE,FILTER([ID],IFERROR(BYROW([Predecessors],LAMBDA(a, OR(TEXTSPLIT(a, ",")+0=[@ID]))),FALSE),""))
				
			

How it works?

For each activity, the list of successors is defined as all the activities that begin immediately after that activity.

So for example, going back to our image of project plan (see below),

project plan (critical path analysis with Excel)

the list of successors for activity 1 is {2,3}

To obtain this list for a given activity x:

  • We need to filter all the activities
  • where x is one of the predecessors

 We can use a cocktail of FILTER(), BYROW(), LAMBDA() and TEXTSPLIT() for this.

Here is the basic approach:

  1. We filter the [ID] column
  2. by checking for each row (hence BYROW)
  3. if the [Predecessor]s has the [@ID]
  4. To perform the check, we first split the predecessors using TEXTSPLIT
  5. and then compare if any of them equal to [@ID]
  6. At the end of this BYROW looping, we end up with either TRUE or FALSE values against each [ID]
  7. After filter fetches all the successors, we just apply TEXTJOIN to combine them to a list. For ex: 2,3

 

Latest Finish Formula (LF)

Latest Finish (LF) is defined as the latest an activity can finish without derailing the project.

For the activities without any successors, this is same as EF.

For all other activities, we look for the minimum (earliest) LS value of all it’s successors.

Here is the formula:

				
					=IF([@Successors]="",[@EF],MIN(CHOOSEROWS([LS],TEXTSPLIT([@Successors],",")+0)))
				
			

How this formula works?

If an activity has no successors (ie it is last activity in the project diagram) we set LF as EF.

For all other activities, we split the [@Succssors] by comma (using TEXTSPLIT) and convert these text values to numbers (by adding a 0 to them). We then pick the minimum of all these activity’s Latest Start time [LS] using MIN & CHOOSEROWS functions.

Latest Start Formula (LS)

This is Latest Finish (LF) minus Duration (T)

				
					=[@LF]-[@[Estimated Duration]]
				
			

Float (or Slack)

Now that we have all the calculations done, we can figure out the float (or slack) for each activity. This is the difference between Latest Start (LS) and Earliest Start (ES) for an activity. 

				
					=[@LS]-[@ES]
				
			

Findout out which activities are on Critical Path

Any activity with ZERO (0) float is on the critical path. It means, there is no wiggle room for that activity. 

We can use Excel’s conditional formatting feature to visually identify all such activities.

  1. Select the table and add a new conditional formatting rule (formula based)
  2. Use the rule float_column=0 and set the necessary formatting. (see my rule in the below screenshot).

Here is my final project plan table with critical path activities identified.

Critical Path Analysis with Excel - FREE Template

Please download my FREE Critical Path Analysis Template and use your own data to calculate the critical path automatically.

 

Critical Path Calculations in Excel - Watch the Video

Still confused about these calculations? I made a video explaining the CPM concept & Excel formulas. Check it out below or on my YouTube Channel.

More on Project Management using Excel

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Excel School made me great at work.
5/5

– Brenda

Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

Announcing Power BI Dashboard Contest 2024

Announcing Power BI Dashboard Contest (win $500 prizes!)

Hey there, I have a SUPER exciting announcement! April is about to get a whole lot sweeter with our Power BI Dashboard Contest! Your mission, should you choose to accept it: Craft the most EPIC dashboard for the Awesome Chocolates CEO with sales & financial insights! Winners stand a chance to score up to $500 in Amazon Gift Cards, plus some serious bragging rights!

8 Responses to “Calculating Critical Path using Excel Formulas [Project Management]”

  1. Jairaj P says:

    Simpler formula for Successors =TEXTJOIN(",",1,FILTER([ID],ISNUMBER(SEARCH([@ID],[Predecessors])),""))

  2. Sandy_X says:

    Very nice solution,
    but, how to substitute ES, EF, LS, LF with real dates?

  3. Pedro Wave says:

    Chandoo, it's not true that these formulas work only in Excel for Microsoft 365. New functions: TEXTSPLIT; CHOOSEROWS and LAMBDA also work in Excel for the web.

    What doesn't work on the Web is the check box button: "Show Critical Path Activities" or any form control.

    To get around that problem when using Excel for the web, manually change cell V3 to TRUE/FALSE.

  4. Kelton Dennis says:

    Hi,

    I'm interested in your Project Management Templates.
    But when I downloaded your "FREE Critical Path Analysis Template" there was a problem.

    I found that altering the duration of any activity caused 28 of the 30 calculation cells to show a "#NAME?" error.

    what's going wrong?
    regards
    Kelton

  5. Sohil Mehta says:

    Hello Chandoo,

    I want to express my gratitude for introducing the critical path method in Excel. It has proven to be incredibly helpful.

    However, I'm currently encountering a challenge. While creating schedules, I adhere to WBS numbering, such as 1.1 and so forth. However, my work packages are further subdivided into activities, and some of my activity numbering includes formats like 1.1.1.

    The current formula is not functioning as expected in these cases. Could you please assist by providing an updated formula to handle such IDs? Additionally, I am curious about how the LF and ES calculations would work if a predecessor has more than one ID in a similar format.

    Thank you for your assistance.

Leave a Reply