How to use the SEQUENCE function
What is the SEQUENCE function?
The SEQUENCE function creates a list of sequential numbers to a cell range or array. It is located in the Math and trigonometry category and is only available to Excel 365 subscribers.
What's on this page
- Introduction
- Syntax
- Example 1
- Example 2 - create a dynamic calendar
- Example 3 - create a repeating sequence
- Example 4 - create repeated numbers in a sequence
- Example 5 - create blanks in a sequence of numbers
- Example 6 - format numbers in sequence with leading zeros
- Example 7 - reverse a list using the SEQUENCE function
- Example 8 - sequence of dates based on a start date
- Example 9 - sequence of months
- Example 10 - sequence of weeks
- Example 11 - sequence of quarters
- Example 12 - sequence of letters
- Example 13 - sequence of cells?
- Alternative to the SEQUENCE function?
- Function not working
- Get Excel file
1. Introduction
What are sequential numbers?
Sequential numbers are a series of numbers that follow a specific order or pattern, typically increasing or decreasing by a consistent amount. They are numbers that come one after another in a logical, predictable order.
They usually start with a specific number and then increase or decrease by a fixed amount called the "step" or "interval". Examples:
- Counting numbers: 1, 2, 3, 4, 5... (step of 1)
- Even numbers: 2, 4, 6, 8, 10... (step of 2)
- Odd numbers: 1, 3, 5, 7, 9... (step of 2)
- Multiples of 5: 5, 10, 15, 20, 25... (step of 5)
- Decreasing sequence: 100, 95, 90, 85... (step of -5)
What are sequential numbers used for?
- Counting and ordering items
- Creating lists or inventories
- Numbering pages or sections in documents
- Programming and algorithms
- Mathematical sequences and patterns
They help in organizing information and are useful in mathematics statistics and data analysis.
What is a spilled array formula?
Excel 365 automatically expands the output range based on the number of values in the array, without requiring the user to enter the formula as an array formula.
This new behavior of Excel is called spilled array formula and is something only dynamic array formulas can do. Dynamic array formulas are only available to Excel 365 subscribers.
Why does the function return a #SPILL! error?
#SPILL! error is returned by the SEQUENCE function if the required cell range is populated by any other value. You have two options:
- Remove value leaving the cell blank.
- Enter the dynamic formula in another cell that has empty adjacent cells.
Why does the function return a #NAME! error?
If a cell returns #NAME! error you have either misspelled the function name or you are using an older incompatible Excel version.
The image above shows that I misspelled the SEQUENCE function in the formula bar, cell F3 displays #NAME! error.
Only Excel 365 subscription version supports the new dynamic array formula like the SEQUENCE function, older Excel versions like Excel 2019, 2016, 2013, 2010, 2007 and earlier versions do not support the SEQUENCE function.
Here is how to find out your Excel version: Get your Excel version
2. Syntax
SEQUENCE(rows, [columns], [start], [step])
Argument | Text |
rows | Required. Number of rows. |
[columns] | Optional. Number of columns, 1 is the default value. |
[start] | Optional. Start number, 1 is the default value. |
[step] | Optional. A number to increment each value in the sequence. |
3. Example 1
Create a sequence of numbers that starts with 65, has 6 rows and 1 column with a step interval of 2?
The arguments are specified in cells E2:E5:
- rows: 6
- [columns]: 1
- [start]: 65
- [step]: 2
Formula in cell B3:
The formula in cell B3, demonstrated in the image above, returns a sequence of six numbers from 65 to 75 with an incremental value of 2. 65, 67, 69, 71, 73, and 75.
4. Example 2
How to create a dynamic calendar?
The image above demonstrates a dynamic array formula in cell C5 that creates dates based on the date in cell C2. Cell E2 is formatted to only show the month and year.
Formula in cell C5:
Change the date in cell C2 and the dates in the calendar are instantly refreshed based on the new date value. The formula is a dynamic array formula and it returns an array of numbers, the array size is six rows and seven columns.
Here is how it works:
- Calculate the weekday number based on the given date in cell C2. WEEKDAY function
- Subtract date with weekday number and add 1. C2-WEEKDAY(C2)+1
- Create a sequence of numbers based on 6 rows and 7 columns, starting from C2-WEEKDAY(C2)+1
The calendar creates dates based on a week that starts with a Sunday.
4.1 Explaining formula in cell C5
Step 1 - Calculate weekday number
The WEEKDAY function converts an Excel date to a number 1 - 7 representing the weekday.
WEEKDAY(C2)
becomes
WEEKDAY(43952)
and returns 6. Friday is the sixth weekday in a week. The week begins with Sunday if you omit the second argument.
1 - Sunday
2- Monday
3- Tuesday
4-Wednesday
5-Thursday
6- Friday
7- Saturday
Step 2 - Calculate the first date in a week
This step calculates the date of the first day of the week. It is most often but not always a date in the last month.
C2-WEEKDAY(C2)+1
becomes
C2-6+1
becomes
43952-6+1
and returns 43947. This number represents a date in Excel. 1/1/1900 is 1, 43947 is 4/6/2020.
Step 3 - Create a sequence
SEQUENCE(6,7,C2-WEEKDAY(C2)+1)
becomes
SEQUENCE(6,7, 43947)
and returns {43947, 43948,..., 43988}.
5. Example 3
How to create a repeating sequence?
The image above demonstrates a formula in cell B3 that creates a sequence from 1 to 3 repeated as far as necessary.
Formula in cell B3:
The formula in cell B3 creates a sequence of numbers that is 9 rows in size. Change the sequence argument to adjust the number of rows.
Change the second argument in the MOD function to adjust the number of values that are repeated. The example above has 3 in the second argument meaning the repeated sequence starts from 1 and goes to 3.
5.1 Explaining formula in cell C5
Step 1 - Create a sequence
SEQUENCE(9)-1
becomes
{1;2;3;4;5;6;7;8;9}-1
and returns {0; 1; 2; 3; 4; 5; 6; 7; 8}.
Step 2 - Calculate remainder
The MOD function returns the remainder after a number is divided by a divisor.
MOD(SEQUENCE(9)-1,3)+1
becomes
MOD({0; 1; 2; 3; 4; 5; 6; 7; 8} ,3)+1
becomes
{0; 1; 2; 0; 1; 2; 0; 1; 2}+1
and returns the following array
{1; 2; 3; 1; 2; 3; 1; 2; 3}.
6. Example 4
How to create repeated numbers in a sequence?
The image above demonstrates a formula in cell B3 that creates a sequence of repeated numbers like 1, 1, 1, 2, 2, 2, 3, 3,... as far as necessary.
Formula in cell B3:
The first argument in the sequence function lets you adjust the number of rows in the output array. The third and fourth argument specifies how many times a number is repeated.
6.1 Explaining formula in cell C5
Step 1 - Create a sequence
SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(9, , 1/3, 1/3)
returns
{0.333333333333333; ...; 3}
Step 2 - Round values up
The ROUNDUP function calculates a number rounded up based on the number of digits to which you want to round the number.
ROUNDUP(number, num_digits)
ROUNDUP(SEQUENCE(9, , 1/3, 1/3), 0)
returns {1; 1; 1; 2; 2; 2; 3; 3; 3}
7. Example 5
How to create empty values in a sequence of numbers?
The image above demonstrates a formula in cell B3 that creates a sequence from 1 to 5 with blanks in every other row.
Formula in cell B3:
The formula can be shortened to:
=LET(x,SEQUENCE(9,,1,1/2),IF(INT(x)=x,x,""))
The first argument in the SEQUENCE function changes the number of rows in the output array. The third argument specifies the start value and the fourth argument specifies where the blank value is put. For example, 1/3 creates a sequence where every third value is displayed.
Explaining formula in cell C5
Step 1 - Create a sequence
SEQUENCE(9, , 1, 1/2)
returns {1; 1.5; 2; 2.5; 3; 3.5; 4; 4.5; 5}.
Step 2 - Create a logical expression
The INT function removes the decimal part from positive numbers.
INT(SEQUENCE(9, , 1, 1/2))=SEQUENCE(9, , 1, 1/2)
returns {TRUE; FALSE; T... ; TRUE}
Step 3 - Replace boolean values
IF(INT(SEQUENCE(9, , 1, 1/2))=SEQUENCE(9, , 1, 1/2), SEQUENCE(9, , 1, 1/2), "")
returns {1;"";2;"";3;"";4;"";5}.
8. Example 6
The image above demonstrates a formula in cell B3 that creates a sequence from 1 to 1 with leading zeros.
Formula in cell B3:
The TEXT function allows you to put leading zeros to the sequence of numbers.
Explaining formula in cell C5
Step 1 - Create a sequence
SEQUENCE(10)
returns
{1; 2; 3; 4; 5; 6; 7; 8; 9; 10}
Step 2 - Format numbers
The TEXT function converts a value to text in a specific format. TEXT(value, format_text)
TEXT(SEQUENCE(10),"000")
returns {"001"; "002"; ... ; "010"}.
9. Example 7
How to reverse a list using the SEQUENCE function?
The image above demonstrates a formula in cell D3 that flips data from cell range B3:B14 meaning the last value is at the top etc.
Formula in cell B3:
This formula can also be shortened which makes it easier to make adjustments to the arguments.
=LET(x,B3:B14,y,ROWS(x),INDEX(x, SEQUENCE(y, , y, -1)))
Adjust cell reference B3:B14 to your needs. This formula works only for a cell range containing one column.
9.1 Explaining formula in cell C5
The formula uses a cell reference to the old list in order to calculate a sequence that begins with a number representing the position of the last item in the list and then adds 1 to the next value until all values have been accounted for.
Step 1 - Calculate rows in the cell reference
ROWS(B3:B14)
returns 12.
Step 2 - Create a sequence
The SEQUENCE function creates a sequence with start value 12 and increments by -1. SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(ROWS(B3:B14), , ROWS(B3:B14), -1)
returns {12; 11; ... ; 1}.
Step 3 - Get values
The INDEX function returns values from a cell range based on a row and column arguments.
INDEX(B3:B14, SEQUENCE(ROWS(B3:B14), , ROWS(B3:B14), -1))
returns {"rose"; "magenta"; ...; "red"}.
10. Example 8
How to create sequential dates?
The image above demonstrates a formula in cell D3 that creates a list of consecutive dates.
Formula in cell B3:
This formula creates a list of sequential dates starting with 1/1/2020 and continues to 1/14/2020. Change the first, second, and third argument to change the start year, month, and day respectively. The first argument in the SEQUENCE function allows you to specify the number of rows in the output array.
Explaining formula in cell C5
Step 1 - Create a sequence
The SEQUENCE function creates a sequence of 15 numbers from 0 (zero) to 14. SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(14,,0)
returns
{0; 1; ...; 13}
Step 1 - Calculate rows in the cell reference
The DATE function returns an Excel date based on three arguments, year, month, and day. DATE(year, month, day)
DATE(2020,1,1)+SEQUENCE(14,,0)
becomes
DATE(2020,1,1)+{0; 1; ...; 13}
becomes
43831+{0; 1; ... ; 13}
and returns
{43831; 43832; ...; 43844}.
11. Create a sequence of months
The image above demonstrates a formula in cell D3 that creates a list of consecutive months starting with 12/1/2021 and ends with 1/1/2021.
Formula in cell B3:
You can easily adjust the formula to create a sequence that increases the month by one instead. Change the minus sign to a plus sign.
Explaining formula in cell C5
Step 1 - Calculate rows in the cell reference
SEQUENCE(12, , 0) creates a sequence of 12 numbers that begins with 0 (zero) and ends with 11.
SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(12, , 0)
returns
{0; 1; 2; ...; 11}
Step 2 - Calculate rows in the cell reference
We are now going to use the array in the month argument, this creates an array of Excel dates beginning with 12-1-2021 and ending with 1-1-2021.
The DATE function creates Excel dates based on a given year, month, and days.
DATE(2021,12-SEQUENCE(12,,0),1)
becomes
DATE(2021,12-{0; 1; ...; 11}, 1)
and returns
{44531; 44501; ....; 44197}.
Step 3 - Calculate rows in the cell reference
The TEXT function formats the Excel dates to mmm-yyyy.
TEXT(DATE(2021,12-SEQUENCE(12,,0),1),"mmm-yyyy")
returns {"Dec-2021"; "Nov-2021"; ... ; "Jan-2021"}
12. Create a sequence of months and corresponding week numbers
The image above demonstrates a formula in cell D3 that creates a list of sequential months and the corresponding weeknumber starting with 12/1/2021 and ends with 1/1/2021.
Formula in cell B3:
Explaining formula in cell C5
Step 1 - Create a sequence from 0 (zero) to 12
SEQUENCE(12, , 0)
returns
{0; 1; ... ; 11}
Step 2 - Create a list of consecutive dates
The DATE function creates Excel dates based on a year, month, and day argument.
DATE(2021, 12-SEQUENCE(12, , 0), 1)
returns {44531; 44501; ... ; 44197}
Step 3 - Change date formatting
The TEXT function formats the dates to m/d/yyyy.
TEXT(DATE(2021, 12-SEQUENCE(12, , 0), 1), "m/d/yyyy")
returns {"12/1/2021"; "11/1/2021"; ... ; "1/1/2021"}
Step 4 - Calculate week number based on date
The ISOWEEKNUM function creates a week number of an Excel date.
ISOWEEKNUM(DATE(2021, 12-SEQUENCE(12, , 0), 1))
becomes
ISOWEEKNUM({44531; ... ; 44197})
and returns {48; 44; ... ; 53}
Step 5 - Concatenate date, text, and week values
The ampersand character & allows you to concatenate text string, numbers, arrays and so on.
TEXT(DATE(2021, 12-SEQUENCE(12, , 0), 1), "m/d/yyyy")&" week: "&ISOWEEKNUM(DATE(2021, 12-SEQUENCE(12, , 0), 1))
returns {"12/1/2021 week: 48"; "11/1/2021 week: 44"; ...; "1/1/2021 week: 53"}
13. Create a sequence of quarters in a year and more
This formula creates a sequential list of four quarters starting with quarter 4 in 2021 going back to 2018 and the first quarter.
Formula in cell B3:
The list has the following formatting: yyyy-Qrt[quarter number]
Explaining formula in cell C5
Step 1 - Create a sequence
SEQUENCE(16,,0,3)
returns
{0; 3; ... ; 45}
Step 2 - Create a sequence of dates
The DATE function creates Excel dates using a year, month and day argument.
DATE(2021,10-SEQUENCE(16,,0,3),1)
becomes
DATE(2021,10-{0; 3; 6; ... ; 45},1)
and returns
{44470; 44378; ....; 43101}
Step 3 - Convert dates to years
The YEAR function returns the year of an Excel date.
YEAR(DATE(2021,10-SEQUENCE(16,,0,3),1))
becomes
YEAR({44470; 44378; ...; 43101})
and returns
{2021; 2021; ...; 2018}
Step 4 - Convert dates to months
The MONTH function returns a number representing the relative position. 1 - January, ... , 12 - December.
MONTH(DATE(2021,10-SEQUENCE(16,,0,3),1))
becomes
MONTH({44470; 44378; ...; 43101})
and returns
{10; 7; ... ; 1}.
Step 5 - Convert months to quarters
The MATCH function returns the relative position of a given value in an array or cell range.
MATCH(MONTH(DATE(2021,10-SEQUENCE(16,,0,3),1)),{0,4,7,10})
becomes
MATCH({10; 7; 4; 1; 10; 7; 4; 1; 10; 7; 4; 1; 10; 7; 4; 1},{0,4,7,10})
and returns
{4; 3; 2; ... ; 1}
Step 6 - Concatenate year, text string and quarter number
The ampersand character & allows you to concatenate text string, numbers, arrays and so on.
YEAR(DATE(2021,10-SEQUENCE(16,,0,3),1))&"-Qrt"&MATCH(MONTH(DATE(2021,10-SEQUENCE(16,,0,3),1)),{0,4,7,10})
returns {"2021-Qrt4";"2021-Qrt3";.... ;"2018-Qrt1"}
14. Create a sequence of letters
The image above demonstrates a formula in cell B3 that creates letters from A to Z.
Formula in cell B3:
The formula returns a vertical array that contains all the upper letters in the English alphabet.
Explaining formula in cell C5
Step 1 - Create a sequence of 26 numbers starting with 65
SEQUENCE(26,,65)
returns
{65; 66; ... ; 90}
Step 2 - Convert numbers to characters
The CHAR function converts a number to the corresponding character which is determined by your computer's character set.
CHAR(SEQUENCE(26,,65))
returns {"A"; "B"; ... ; "Z"}
15. Create a sequence of cells
The image above shows a formula in cell B3 that returns values from given a list and repeats those values four times.
Formula in cell B3:
The list is cell range D3:D5 and contains fruit names: Banana, Orange, and Apple. These items are repeated in an array with 11 containers.
Explaining formula in cell C5
Step 1 - Create a sequence from 0 (zero) to 11
To create a sequence from 0 (zero) to 11 we need to specify the first and third argument.
SEQUENCE(rows, [columns], [start], [step])
SEQUENCE(11, , 0)
returns {0; ... ; 10}.
Step 2 - Create a repeating list of numbers
The MOD function returns the remainder after a number is divided by a divisor. MOD(number, divisor)
MOD(SEQUENCE(11,,0),3)
returns {0; 1; 2; 0; 1; 2; 0; 1; 2; 0; 1}
Step 3 - Get values from cell range
The INDEX function returns values from a cell range based on a row and column arguments.
INDEX(D3:D5,MOD(SEQUENCE(11,,0),3)+1)
returns {"Banana"; "Orange"; ... ; "Orange"}.
16. Alternative function
The image above shows the SEQUENCE function in cell B3 and F3, cell D3 and F8 demonstrates alternative ways to create arrays if you can't use the SEQUENCE function.
The alternative formula in cell D3 creates an array of numbers from 1 to 10 in one column. The other alternative formula in cell F8 creates an array of numbers from 1 to 9 in three columns and three rows.
Formula in cell B3:
Alternative formula in cell D3:
Formula in cell F3:
Alternative formula in cell F8:
17. Function not working
The SEQUENCE function returns
- #VALUE! error if you use a non-numeric input value.
- #NAME? error if you misspell the function name.
- propagates errors, meaning that if the input contains an error (e.g., #VALUE!, #REF!), the function will return the same error.
- #SPILL! error if the destination range is not empty.
17.1 Troubleshooting the error value
When you encounter an error value in a cell a warning symbol appears, displayed in the image above. Press with mouse on it to see a pop-up menu that lets you get more information about the error.
- The first line describes the error if you press with left mouse button on it.
- The second line opens a pane that explains the error in greater detail.
- The third line takes you to the "Evaluate Formula" tool, a dialog box appears allowing you to examine the formula in greater detail.
- This line lets you ignore the error value meaning the warning icon disappears, however, the error is still in the cell.
- The fifth line lets you edit the formula in the Formula bar.
- The sixth line opens the Excel settings so you can adjust the Error Checking Options.
Here are a few of the most common Excel errors you may encounter.
#NULL error - This error occurs most often if you by mistake use a space character in a formula where it shouldn't be. Excel interprets a space character as an intersection operator. If the ranges don't intersect an #NULL error is returned. The #NULL! error occurs when a formula attempts to calculate the intersection of two ranges that do not actually intersect. This can happen when the wrong range operator is used in the formula, or when the intersection operator (represented by a space character) is used between two ranges that do not overlap. To fix this error double check that the ranges referenced in the formula that use the intersection operator actually have cells in common.
#SPILL error - The #SPILL! error occurs only in version Excel 365 and is caused by a dynamic array being to large, meaning there are cells below and/or to the right that are not empty. This prevents the dynamic array formula expanding into new empty cells.
#DIV/0 error - This error happens if you try to divide a number by 0 (zero) or a value that equates to zero which is not possible mathematically.
#VALUE error - The #VALUE error occurs when a formula has a value that is of the wrong data type. Such as text where a number is expected or when dates are evaluated as text.
#REF error - The #REF error happens when a cell reference is invalid. This can happen if a cell is deleted that is referenced by a formula.
#NAME error - The #NAME error happens if you misspelled a function or a named range.
#NUM error - The #NUM error shows up when you try to use invalid numeric values in formulas, like square root of a negative number.
#N/A error - The #N/A error happens when a value is not available for a formula or found in a given cell range, for example in the VLOOKUP or MATCH functions.
#GETTING_DATA error - The #GETTING_DATA error shows while external sources are loading, this can indicate a delay in fetching the data or that the external source is unavailable right now.
17.2 The formula returns an unexpected value
To understand why a formula returns an unexpected value we need to examine the calculations steps in detail. Luckily, Excel has a tool that is really handy in these situations. Here is how to troubleshoot a formula:
- Select the cell containing the formula you want to examine in detail.
- Go to tab “Formulas” on the ribbon.
- Press with left mouse button on "Evaluate Formula" button. A dialog box appears.
The formula appears in a white field inside the dialog box. Underlined expressions are calculations being processed in the next step. The italicized expression is the most recent result. The buttons at the bottom of the dialog box allows you to evaluate the formula in smaller calculations which you control. - Press with left mouse button on the "Evaluate" button located at the bottom of the dialog box to process the underlined expression.
- Repeat pressing the "Evaluate" button until you have seen all calculations step by step. This allows you to examine the formula in greater detail and hopefully find the culprit.
- Press "Close" button to dismiss the dialog box.
There is also another way to debug formulas using the function key F9. F9 is especially useful if you have a feeling that a specific part of the formula is the issue, this makes it faster than the "Evaluate Formula" tool since you don't need to go through all calculations to find the issue.
- Enter Edit mode: Double-press with left mouse button on the cell or press F2 to enter Edit mode for the formula.
- Select part of the formula: Highlight the specific part of the formula you want to evaluate. You can select and evaluate any part of the formula that could work as a standalone formula.
- Press F9: This will calculate and display the result of just that selected portion.
- Evaluate step-by-step: You can select and evaluate different parts of the formula to see intermediate results.
- Check for errors: This allows you to pinpoint which part of a complex formula may be causing an error.
The image above shows cell reference B3 converted to hard-coded value using the F9 key. The SEQUENCE function requires numerical values which is not the case in this example. We have found what is wrong with the formula.
Tips!
- View actual values: Selecting a cell reference and pressing F9 will show the actual values in those cells.
- Exit safely: Press Esc to exit Edit mode without changing the formula. Don't press Enter, as that would replace the formula part with the calculated value.
- Full recalculation: Pressing F9 outside of Edit mode will recalculate all formulas in the workbook.
Remember to be careful not to accidentally overwrite parts of your formula when using F9. Always exit with Esc rather than Enter to preserve the original formula. However, if you make a mistake overwriting the formula it is not the end of the world. You can “undo” the action by pressing keyboard shortcut keys CTRL + z or pressing the “Undo” button
17.3 Other errors
Floating-point arithmetic may give inaccurate results in Excel - Article
Floating-point errors are usually very small, often beyond the 15th decimal place, and in most cases don't affect calculations significantly.
'SEQUENCE' function examples
First, let me explain the difference between unique values and unique distinct values, it is important you know the difference […]
This blog article describes how to split strings in a cell with space as a delimiting character, like Text to […]
In this blog post I will demonstrate methods on how to find, select, and deleting blank cells and errors. Why […]
Functions in 'Math and trigonometry' category
The SEQUENCE function function is one of 62 functions in the 'Math and trigonometry' category.
Excel function categories
Excel categories
3 Responses to “How to use the SEQUENCE function”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Hi Oscar,
Can an Array Formula replicate the "Step" feature offered by Sequence ?
The objective for the Array Formula is to create {1,4,7,10,13}
Thanks for your insight
Hi again,
For Future Readers ...
Found a solution as follows :
=((ROW(INDIRECT("1"&":"&"5"))*2)-1)+(ROW(INDIRECT("1"&":"&"5"))-1)
James,
thank you for commenting!
Here is another solution:
=(ROW(A1:A5)-1)*3+1