Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Patterns of Numbers with a Formula.
Written by Allen Wyatt (last updated August 20, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Helen has used a macro to generate a simple pattern of numbers. The pattern, which is contained in a single column, looks like this:
1,1,0,2,2,0,3,3,0,4,4,0,...
Helen was wondering if there is a way to generate the same pattern using a formula instead of a macro.
Actually, there are several different formulas you can use to achieve the desired pattern. One way is to start with your seed sequence (1, 1, 0) in cells A1 through A3. Then, enter the formula =A1+1 into cell A4, the formula =A4 into cell A5, and the formula =A3 into cell A6. Now you can select the cells in A4:A6 and use the fill handle to drag and fill however many rows you need.
A different formulaic approach is to still put your seed sequence (1, 1, 0) in cells A1 through A3, and then enter the following formula into cell A4:
=IF(A1<>0,A1+1,0)
You can copy this formula down as many cells as necessary to repeat the desired pattern.
If you don't want to use a seed sequence (for instance, the sequence will always start with 1, 1, 0), then can use a straight formula starting with cell A1. Either of the following formulas will produce the same results:
=IF(MOD(ROW(),3)=0,0,INT(ROW()/3)+1) =(INT(ROW()/3)+1)*(MOD(ROW(),3)<>0)
The formulas (and many variations of these formulas) examine the row in which the formula is positioned, and then figure out whether it is in the first, second, or third row of each set. Based on this position, the formula figures out whether it should show the "set number" (1, 2, 3, etc.) or a zero value.
If your pattern doesn't start in the first row of a worksheet, you need to adjust the formula to account for an offset from the first row. For instance, if the pattern is going to start in the second row (you may have a header in the first row), then the formulas can be adjusted in this manner:
=IF(MOD(ROW()-1,3)=0,0,INT((ROW()-1)/3)+1) =(INT((ROW()-1)/3)+1)*(MOD(ROW()-1,3)<>0)
Simply put the formula into the second row and copy it down, as required. To adjust the offset for any other row, just change the -1 values (two of them in each formula) to the number of rows you have pushed down the formula from the first row.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11988) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Patterns of Numbers with a Formula.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
If you keep phone numbers in an Excel worksheet, you may need a way to add an area code to the beginning of all of the ...
Discover MoreThe filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...
Discover MoreWhen you store textual information in a worksheet, it can be helpful to figure out if that information follows a pattern ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments