Written by Allen Wyatt (last updated March 18, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Robert is looking for a way to determine the business quarter in which a particular date falls. For example, if cell A1 has 2/15/08, he would want cell B1 to contain a formula that returned Q1-08. Similarly, if cell A1 has 8/1/07, he would want cell B1 to return Q3-07.
There are literally dozens of ways that you can determine a straight business quarter from a date. A few of these methods are worth examining, and they are easily modified to adapt to any specific needs. What is assumed here is that you really want to use a self-contained formula, rather than using a lookup table or a VBA macro. Both of those approaches will work just fine, but it is assumed that the simple formulas will work best for your purposes.
The key factor in determining the business quarter is to look at the month of the date. One way to do that examination is to use a formula that relies on the CHOOSE function. Consider the following:
=CHOOSE(MONTH(A1),"Q1","Q1","Q1","Q2","Q2", "Q2","Q3","Q3","Q3","Q4","Q4","Q4") & "-" & RIGHT(YEAR(A1),2)
This is a single formula; it is rather long, providing a choice for each of the 12 months in the year. Each month returns the quarter portion of the result, and then the text for the year is appended.
Another way is to rely on IF statements to determine the quarter. This is done in the following manner:
=IF(MONTH(A1)<=3,"Q1",IF(MONTH(A1)<=6,"Q2", IF(MONTH(A1)<=9,"Q3","Q4")))&"-"&TEXT(A1,"yy")
The IF statements check the month to see its relation to the various boundaries for the quarters (3, 6, and 9) and then assigns a proper quarter (Q1, Q2, Q3, or Q4) based on the result. A dash and the last two digits of the year is then appended to the quarter.
You can make the formula even shorter by calculating the quarter directly based upon the month. For instance, the following will take the month and return a value of 1 to 4 based on the month:
=INT((MONTH(A1)-1)/3)+1
This formula can be incorporated into a larger formula in this way:
="Q" & INT((MONTH(A1)-1)/3)+1 & "-" & RIGHT(YEAR(A1),2)
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3339) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Determining Business Quarters from Dates.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
If you have a list of data in a column, you may want to determine an average of whatever the last few items are in the ...
Discover MoreExcel allows you to enter two different types of formulas in a cell: A regular formula or an array formula. If you need ...
Discover MorePostal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-01-23 15:21:45
Willy Vanhaelen
Here is a much shorter alternative for the first formula:
="Q"&MID("111222333444",MONTH(A1),1)&TEXT(A1,"-yy")
2017-05-30 06:27:13
Michael (Micky) Avidan
Meaning: =INT((MONTH(A1)+2)/3)
2017-05-30 06:25:14
Michael (Micky) Avidan
You may want to add, to the list, the shortest formula known (to me) so far:
=INT((MONTH(C2)+2)/3)
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” Excel MVP – Excel (2009-2017)
ISRAEL
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments