How to use the ROWS function
What is the ROWS function?
The ROWS function allows you to calculate the number of rows in a cell range.
The example above shows that cell range B3:B10 contains 8 rows.
Table of Contents
1. Introduction
What is a cell reference?
A cell reference in Excel is a way to identify and refer to a specific cell or range of cells within a spreadsheet. Cell references are fundamental to Excel's functionality, allowing users to create dynamic, interconnected spreadsheets.
What is the cell reference structure?
It depends if the cell reference points to a single cell or a cell range containing multiple cells. A single cell reference typically consists of a column letter followed by a row number (e.g., A1, B2, C3).
A cell range reference points to multiple cells, for example: A1:B10. Note that the colon separates the first cell reference and the second cell reference. The first cell reference indicates the top-left cell in the specified cell range, while the second cell reference denotes the bottom-right cell in that same range. These two cell references determines the height in rows and width in columns, of the cell range. Cell range references are used in functions that perform calculations or operations on a group of cells, rather than just a single cell.
Both single cell and multi-cell references can also include sheet names for referencing cells in other worksheets. For example, Sheet!A1 or Sheet2!B2:B10. Note that Excel requires an exclamation mark between the sheet name and the cell reference. You can find the Sheet names your workbook contains, at the very bottom to the left. Single quotation marks are used if the worksheet name contains a space character, example: 'Budget 2027'!B3
What are the different cell reference types?
- Relative: The cell reference changes when the cell is copied or moved. For example: A1
- Absolute: The cell reference is fixed and doesn't change when copied. The dollar signs lets you specify which part of the cell reference you want to be abolute. For example: $A$1
- Mixed: One part fixed, one part relative. $A1 or A$1
When are cell references used?
In formulas to perform calculations using values from other cells. For data validation, conditional formatting, and other Excel features. To link data between different sheets or workbooks.
2. Syntax
ROWS(array)
array | Required. A cell range for which you want to calculate the number of rows. |
3. Example
Formula in cell D3:
4. Count rows in an array
The ROWS function also calculates the number of rows in an array. This example demonstrates how to count rows in a hard coded array. An array is a collection of values that can be used in formulas and functions. It's a way to store and manipulate multiple values as a single unit.
A hard-coded array in Excel is an array that is explicitly defined within a formula using curly brackets {}. For example: {1, 2, 3, 4, 5}. This type of array is also known as a "constant array" or "literal array".
Formula in cell B3:
The array has four rows. The ; (semicolon) character is a row delimiting character in an array.
The delimiting characters in an array in Excel are:
- Commas (,) to separate values horizontally into columns. Using only column separated delimiters creates a one-dimensional array (e.g. {1, 2, 3, 4, 5}) The same thing applies if you only use row delimiters
- Semicolons (;) to separate values into rows in a two-dimensional array (e.g. {1, 2; 3, 4; 5, 6})
- Curly brackets {} to enclose the entire array
5. Count rows based on a condition
This formula is used to count the number of rows in a range that meet a specific condition. In other words, this formula is counting the number of cells in the range B3:B10 that have the same value as cell D3.
Formula in cell E3
Here is a breakdown of how it works:
- B3:B10 is the range of cells that we want to filter.
- D3 is the value that we want to match in the range.
- FILTER(B3:B10,B3:B10=D3) filters the range to only include cells that are equal to the value in cell D3.
- ROWS then counts the number of rows in the filtered range.
Explaining formula
Step 1 - Logical expression
The equal sign lets you compare value to value, it is also possible to compare a value to an array of values. The result is either TRUE or FALSE.
B3:B10=D3
becomes
{"A"; "B"; "B"; "A"; "B"; "B"; "A"; "A"}="A"
and returns
{TRUE; FALSE; FALSE; TRUE; FALSE; FALSE; TRUE; TRUE}.
Step 2 - Filter values based on a condition
The FILTER function gets values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(B3:B10,B3:B10=D3)
becomes
FILTER({"A"; "B"; "B"; "A"; "B"; "B"; "A"; "A"}, {TRUE; FALSE; FALSE; TRUE; FALSE; FALSE; TRUE; TRUE})
and returns
{"A"; "A"; "A"; "A"}.
Step 3 - Count rows
ROWS(FILTER(B3:B10,B3:B10=D3))
becomes
ROWS({"A"; "A"; "A"; "A"})
and returns 4.
6. Count rows based on a list
Formula in cell F3:
Explaining formula
Step 1 - Which values equal any item in the list
The COUNTIF function counts the number of cells that meet a given condition.
COUNTIF(range, criteria)
COUNTIF(E3:E4, C3:C11)
becomes
COUNTIF({"Clip"; "Pen"},{"Pen"; "Pencil"; "Clip"; "Pen"; "Clip"; "Pencil"; "Pen"; "Clip"; "Clip"})
and returns {1; 0; 1; 1; 1; 0; 1; 1; 1}.
Step 2 - Filter values based on array
The FILTER function gets values/rows based on a condition or criteria.
FILTER(array, include, [if_empty])
FILTER(C3:C11,COUNTIF(E3:E4,C3:C11))
becomes
FILTER({"Pen"; "Pencil"; "Clip"; "Pen"; "Clip"; "Pencil"; "Pen"; "Clip"; "Clip"}, {1; 0; 1; 1; 1; 0; 1; 1; 1})
and returns
{"Pen"; "Clip"; "Pen"; "Clip"; "Pen"; "Clip"; "Clip"}.
Step 3 - Count rows
ROWS(FILTER(C3:C11,COUNTIF(E3:E4,C3:C11)))
becomes
ROWS({"Pen"; "Clip"; "Pen"; "Clip"; "Pen"; "Clip"; "Clip"})
and returns 7.
7. Count rows in a delimited string
The formula in cell D3 counts delimited values in a string located in cell B3, you can use any character or string a s a delimiting character.
Excel 365 dynamic array formula in cell C3:
Explaining formula
Step 1 - Split string using a given delimiting character
The TEXTSPLIT function lets you split a string into an array across columns and rows based on delimiting characters.
TEXTSPLIT(B3,,";")
becomes
TEXTSPLIT("|7|45|31||37|98||6",,";")
and returns
{""; "7"; "45"; "31"; ""; "37"; "98"; ""; "6"}.
The semicolon is a delimiting character in arrays, however, they are determined by your regional settings. In other words, you may be using other delimtiing characters.
Step 2 - Count rows
ROWS(TEXTSPLIT(B3,,";"))
becomes
ROWS({""; "7"; "45"; "31"; ""; "37"; "98"; ""; "6"})
and returns 9. The values in the array are arranged vertically. An horizontal array would be using commas, like this: {"", "7", "45", "31", "", "37", "98", "", "6"}.
8. Count rows in multiple cell ranges
This example demonstrate how to count rows in three different sized cell ranges simultaneously and return total rows.
Formula in cell B12:
Explaining formula
Step 1 - Join arrays
The VSTACK function combines cell ranges or arrays, it joins data to the first blank cell at the bottom of a cell range or array.
VSTACK(array1,[array2],...)
VSTACK(B3:B9, D3:D7, F3:F5)
becomes
VSTACK({7; 25; 82; 43; 25; 10; 21},{73; 13; 93; 25; 10; 65; 91},{43; 11; 97; 61; 4; 45; 91})
and returns
{7; 25; 82; 43; 25; 10; 21; 73; 13; 93; 25; 10; 65; 91; 43; 11; 97; 61; 4; 45; 91}.
Step 2 - Calculate rows
ROWS(VSTACK(B3:B9,D3:D7,F3:F5))
becomes
ROWS({7; 25; 82; 43; 25; 10; 21; 73; 13; 93; 25; 10; 65; 91; 43; 11; 97; 61; 4; 45; 91})
and returns 15.
Useful links
ROWS function - Microsoft
ROWS Formula in Excel: Explained
'ROWS' function examples
First, let me explain the difference between unique values and unique distinct values, it is important you know the difference […]
This post explains how to lookup a value and return multiple values. No array formula required.
In this blog post I will demonstrate methods on how to find, select, and deleting blank cells and errors. Why […]
Functions in 'Lookup and reference' category
The ROWS function function is one of 25 functions in the 'Lookup and reference' category.
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.
Contact Oscar
You can contact me through this contact form