Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Patterns of Numbers with a Formula.

Patterns of Numbers with a Formula

by Allen Wyatt
(last updated September 21, 2019)

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 (2889) 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: Patterns of Numbers with a Formula.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Converting to Hexadecimal

Excel allows you to easily convert values from decimal to other numbering systems, such as hexadecimal. This tip explains ...

Discover More

Sorting Text as Numbers

When you are sorting by text values, Excel can be very literal, which may not get you the sorting that you want. This tip ...

Discover More

Intelligently Starting a New Paragraph

When using styles in a document, you can increase your productivity by letting Word know what paragraph style you expect ...

Discover More

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!

More ExcelTips (menu)

Complex Lookup Formulas

If you need to combine information in some of your cells in order to produce a result needed to, in turn, look up other ...

Discover More

Dealing with Circular References

Circular references occur when a formula includes a reference to the cell in which the formula appears. Here's how you ...

Discover More

Combining Numbers and Text in a Cell

There are times when it can be beneficial to combine both numbers and text in the same cell. This can be easily done ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is six more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.