Summary

To get a standard month number from a month name (i.e. 1 from "January", 2 from "February", 3 from "March", etc.) you can use the MONTH function and a bit of concatenation. In the example shown, the formula in cell C5 is:

=MONTH(B5&1)

As the formula is copied down the column, it returns the correct number for each month.

Generic formula

=MONTH("name"&1)

Explanation 

In this example, the goal is to return a number, 1-12, for any month name of the year. For example, given the string "January" we want to return 1, "February" should return 2, and so on. If we had a valid Excel date, we could use a number format for this task, but because we are starting with a text string, we need another way. The approach we take in this example is to create a date fragment that can be correctly interpreted by Excel as a valid date. In the example shown, the formula in cell C5 is:

=MONTH(B5&1) // returns 1

Working from the inside out, we start by concatenating the name in cell B5 to the number 1:

B5&1 // returns "January1"

This expression returns a string like "January1", "February1", "March1",and so on. It turns out, that if we pass a date fragment like this into the MONTH function, it will coerce the string to a valid date, using the current year.  As I write this, the year is 2021, so the result for January is the date January 1, 2021, represented in Excel as the serial number 44197.

After this date has been created, the MONTH function returns the correct month number for the date that was created using concatenation. In each case, the actual date value is a "throwaway", used only as a convenient value to pass into the MONTH function. In B5 the evaluation works like this (in the year 2021):

=MONTH(B5&1)
=MONTH("January1")
=MONTH(44197)
=1

Date evaluation

This example is a bit tricky in that the evaluation of the date inside the MONTH function is automatic. If you use the expression that concatenates the month name to 1 outside the MONTH function, you'll need to add an extra step to get Excel to convert the text to a date.  The DATEVALUE function or adding zero are both good options:

=DATEVALUE(B5&1)
=(B5&1)+0

Both will return a date serial number, which must then be formatted as a date.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.