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:
We can use below notation when capturing this data in Excel table.
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:

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),

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:
- We filter the [ID] column
- by checking for each row (hence BYROW)
- if the [Predecessor]s has the [@ID]
- To perform the check, we first split the predecessors using TEXTSPLIT
- and then compare if any of them equal to [@ID]
- At the end of this BYROW looping, we end up with either TRUE or FALSE values against each [ID]
- 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.
- Select the table and add a new conditional formatting rule (formula based)
- 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
If you are a project manager, you are going to love my site. I have articles & templates on all aspects of Project Management. Check them out below:
















12 Responses to “Analyzing Search Keywords using Excel : Array Formulas in Real Life”
Very interesting Chandoo, as always. Personally I find endless uses for formulae such as {=sum(if(B$2:B$5=$A2,$C$2$C$5))}, just the flexibility in absolute and relative relative referencing and multiple conditions gives it the edge over dsum and others methods.
I've added to my blog a piece on SQL in VBA that I think might be of interest to you http://aviatormonkey.wordpress.com/2009/02/10/lesson-one-sql-in-vba/ . It's a bit techie, but I think you might like it.
Keep up the good work, aviatormonkey
Hi Chandoo,
You might find this coded solution I posted on a forum interesting.
http://www.excelforum.com/excel-programming/680810-create-tag-cloud-in-vba-possible.html
[...] under certain circumstances. One of the tips involved arranging search keywords in excel using Array Forumlas. Basically, if you need to know how frequent a word or group of keywords appear, you can use this [...]
@Aviatormonkey: Thanks for sharing the url. I found it a bit technical.. but very interesting.
@Andy: Looks like Jarad, the person who emailed me this problem has posted the same in excelforum too. Very good solution btw...
Realy great article
"You can take this basic model and extend it to include parameters like number of searches each key phrase has, how long the users stay on the site etc. to enhance the way tag cloud is generated and colored."
How would you go about doing this? I think it would need some VB
Hi,
I found the usage very interesting, but is giving me hard time because the LENs formula that use ranges are not considering the full range, in other words, the LEN formula is only bringing results from the respective "line" cell.
Using the example, when I place the formula to calculate the frequency for "windows" brings me only 1 result, not 11 as displayed in the example. It seems that the LEN formula using ranges is considering the respective line within the range, not the full range.
Any hint?
@Thiago
You have to enter the formula as an Array Formula
Enter the Formula and press Ctrl+Shift+Enter
Not just Enter
Thank you, Hui! I couldn't work out how this didn't work
is there a limit to the number of lines it can analyse.
Ie i am trying to get this to work on a list of sentances 1500 long.
@Gary
In Excel 2010/2013 Excel is only limited by available memory,
So just give it a go
As always try on a copy of the file first if you have any doubts
Apologies if I am missing something, but coudn't getting frequency be easier with Countif formula. Something like this - COUNTIF(Range with text,"*"&_cell with keyword_&"*")
Apologies if I missed, but what is the Array Formula to:
1. Analyze a list of URL's or a list of word phrases to understand frequency;
2. List in a nearby column from most used words to least used words;
3. Next to the list of words the count of occurrences.