How to use the AND function
The image above demonstrates the AND function with two logical expressions. If the value in column B is equal to "North" and the value on the same row in column C is above 500 the AND function returns TRUE. These conditions are only met on row 6.
Formula in cell D3:
This article demonstrates how to use the AND function.
Table of Contents
1. Syntax
AND(logical1, [logical2], ...)
The AND function allows you to perform a logical test in each argument and if all arguments return TRUE the AND function returns TRUE. If at least one argument returns FALSE the AND function returns FALSE.
2. Arguments
logical1 | Required. A logical expression or a function that returns a number. |
[logical2] | Optional. Also a logical expression or a function that returns a number. You can have up to 254 arguments. |
3. How to use numerical values
The AND function arguments can result in TRUE or FALSE, however, it also treats all numbers, both positive and negative, as TRUE.
The exception to that is 0 (zero) which is treated the same as FALSE.
4. How to use an array
The AND function also allows you to not only compare a single cell value but also an entire cell range.
Formula in cell E3:
To enter the formula above as an array formula, type the formula in a cell. Press and hold CTRL + SHIFT keys simultaneously, then press Enter once. Release all keys. The formula is now enclosed with curly brackets, they indicate you successfully entered the formula as an array formula. Don't enter the curly brackets yourself.
4.1 Explaining formula in cell E3
Step 1 - Check if array values are larger than the condition
The larger than character is a logical operator that returns boolean value TRUE if the value is larger than a condition and FALSE if not.
B3:B7>130
becomes
{123; 121; 145; 119; 154}>130
An array may contain values arranged in a single column/row or in a 2D array meaning multiple columns and rows.
{123; 121; 145; 119; 154}>130
and returns
{FALSE; FALSE; TRUE; FALSE; TRUE}
Step 2 - Evaluate AND function
The formula in cell D3 checks if each value in cell range B3:B7 is larger than 130. Three values are not larger than 130 so the AND function returns FALSE.
AND(B3:B7>130)
becomes
AND({FALSE; FALSE; TRUE; FALSE; TRUE})
and returns FALSE. All booleans values must be TRUE for the AND function to return TRUE.
4.2 How to use multiple arrays
The array formula above in cell E3 has two arguments containing a logical expression in each. The first argument checks if values in cell range C3:C7 are larger than 100.
Formula in cell E3:
Step 1 - First condition
C3:C7>100
becomes
{123; 121; 145; 119; 154}>100
and returns
{TRUE; TRUE; TRUE; TRUE; TRUE}
Step 2 - Second condition
The second argument checks if values in cell range B3:B7 are not empty.
B3:B7<>""
becomes
{"North";"South";"East";"West";"West"}<>""
and returns
{TRUE; TRUE; TRUE; TRUE; TRUE}.
Step 3 - Evaluate AND function
All values are TRUE so the AND function returns TRUE.
AND(C3:C7>100,B3:B7<>"")
becomes
AND({TRUE;TRUE;TRUE;TRUE;TRUE},{TRUE; TRUE; TRUE; TRUE; TRUE}) and returns TRUE.
There are two separate arrays in the AND function, however, it doesn't matter. All values must be TRUE or its numerical equivalent to return TRUE.
5. IF function example
The image above demonstrates a formula that combines the AND function and the IF function. If the "Region" is equal to "North" and the "Amount" on the same row is above 200 then multiply with 1.2.
If not return the amount only.
Formula in cell E3:
5.1 Explaining formula in cell E3
Step 1 - First condition
The equal sign is a logical operator that returns boolean value TRUE if a value matches another value. It returns FALSE if not.
B3="North"
becomes
"North"="North"
and returns TRUE.
Step 2 - Second condition
The larger than sign is a logical operator that returns boolean value TRUE if a value is larger than another value. It returns FALSE if not.
C3>200
becomes
400>200
and returns TRUE.
Step 3 - Evaluate AND function
The AND function returns TRUE if all arguments evaluates to TRUE.
AND(B3="North", C3>200)
becomes
AND(TRUE, TRUE)
Step 4 - Calculate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(AND(B3="North", C3>200), 1.2*C3, C3)
becomes
IF(TRUE, 1.2*C3, C3)
becomes
IF(TRUE, 1.2*400, C3)
and returns 480.
6. Working with text
The formula in cell E3 checks if cell B3 is equal to a given text condition and cell C3 is equal to another given text condition, both conditions must be met to returns "Match!".
Cell E6 returns "Match!", both conditions are met.
Formula in cell E3:
6.1 Explaining formula in cell E3
Step 1 - First condition
The equal sign lets you compare value to value, it is a logical operator and returns a boolean value TRUE or FALSE.
B3="North"
becomes
"North" = "North"
and returns TRUE.
Step 2 - Second condition
C3="Calgary")
becomes
"Quebec"="Calgary")
and returns FALSE.
Step 3 - Evaluate AND function
The AND function returns TRUE if all arguments are TRUE.
AND(B3="North", C3="Calgary")
becomes
AND(TRUE, FALSE)
and returns FALSE.
Step 4 - Evaluate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(AND(B3="North", C3="Calgary"), "Match!", "")
becomes
IF(FALSE, "Match!", "")
and returns "".
7. Conditional formatting
The image above shows two cells highlighted by the Conditional formatting formula applied to cell range B3:C8. The conditions are specified in cells E3:F3 respectively.
Both values in columns B and C are highlighted if they match the conditions, the example above shows cell B5:C5 highlighted, they match cells E3 and F3.
Conditional formatting formula in cell B3:
7.1 How to apply Conditional Formatting?
- Select cell range B3:C8.
- Go to tab "Home" on the ribbon.
- Press with the mouse on the "Conditional Formatting" button.
A popup menu appears. - Press on "New Rule...". A popup menu appears.
- Select "Use a formula to determine which cells to format".
- Paste the formula above to "Format values where this is true:".
- Press the OK button.
7.2 Explaining conditional formatting formula in cell B3
Step 1 - First condition
The equal sign lets you compare value to value, it is a logical operator and returns a boolean value TRUE or FALSE.
The dollar sign lets you lock the column or the row number. When the Conditional Formatting tool moves from cell to cell in cell range B3:C8 cell $B3 stays in column B, however, it may freely move to rows below.
$E$3=$B3
becomes
"East" = "North"
and returns FALSE.
Step 2 - Second condition
Reference $C3 is locked to column C.
$F$3=$C3
becomes
"Tokyo"="Santiago"
and returns FALSE.
Step 3 - Evaluate AND function
The AND function returns TRUE if all arguments are TRUE.
AND($E$3=$B3, $F$3=$C3)
becomes
AND(TRUE, TRUE)
and returns TRUE.
8. Get Excel *.xlsx file
9. Multiple conditions
The AND function allows you to have multiple conditions in an IF function, you can have up to 254 arguments. An argument is an input value given to a function. You construct a logical expression that you use as an argument in the AND function.
Table of Contents
- IF with AND function - two logical expressions
- IF with AND function - multiple pairs of logical expressions
- Using arrays in the AND function
- Get Excel file
9.1. IF with AND function - two logical expressions
Formula in cell D3:
9.1.1 Explaining formula in cell D3
The IF function above checks two conditions, the "Region" value must match a text string and the "Amount" value must be larger than a number. If both conditions return TRUE the AND function returns TRUE.
IF REGION = value AND Amount > number then TRUE Else FALSE
In other words, all logical tests in each argument in the AND function must return TRUE for the AND function to return TRUE. The AND function returns FALSE if at least one argument returns FALSE.
Step 1 - Check if value equals condition
The equal sign compares value to value, it returns a boolean value TRUE or FALSE.
B3="South America" becomes "North America"="South America" and returns FALSE.
Step 2 - Check if the number is greater than the condition
The larger than character lets you check if a value is larger than another value, it also returns a boolean value TRUE or FALSE.
C3>5
becomes
5>5
and returns FALSE. Five is not larger than five.
Step 3 - Evaluate AND function
The AND function returns a boolean value TRUE or FALSE if all arguments evaluate to TRUE or the numerical equivalent which is one.
AND(B3="South America", C3>5)
becomes
AND(FALSE, FALSE)
and returns FALSE.
Step 4 - Evaluate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(AND(B3="South America", C3>5), TRUE, FALSE)
becomes
IF(FALSE, TRUE, FALSE)
and returns FALSE.
9.1.2 Alternative formula
You can shorten the formula somewhat by enclosing each logical expression with parentheses and then multiply the conditions.
Formula in cell D4:
Step 1 - Check the first condition
The first logical expression in cell B4 is (B4="South America") and it returns TRUE.
B4="South America"
becomes
"South America"="South America"
and returns TRUE.
Step 2 - Check the second condition
The second expression (C4>5) also returns TRUE.
C4>5
becomes
7>5
and returns TRUE.
Step 3 - Multiply boolean values
(B4="South America")*(C4>5)
becomes
TRUE * TRUE
equals 1. TRUE multiplied by TRUE is 1. TRUE is the same thing as 1 and FALSE is 0 (zero). If you multiply boolean values the outcome is always 0 (zero) or 1.
Step 4 - Evaluate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF((B4="South America")*(C4>5), TRUE, FALSE)
becomes
IF(TRUE, TRUE, FALSE)
and returns TRUE.
9.2. Multiple pairs of criteria
The formula in cell D3 checks if any of the criteria pairs in cell range F4:G6 matches cell B3 and C3 respectively.
Formula in cell D3:
9.2.1 Explaining formula in cell D3
Step 1 - Check multiple conditions
The COUNTIFS function calculates the number of cells across multiple ranges that equals all given conditions.
It allows you to use up to 254 arguments or 127 criteria pairs.
Excel Function Syntax
COUNTIFS(criteria_range1, criteria1, [criteria_range2, criteria2]…)
COUNTIFS($F$4:$F$6,B3,$G$4:$G$6,C3) returns 0 (zero).
Step 2 - Evaluate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(COUNTIFS($F$4:$F$6,B3,$G$4:$G$6,C3), TRUE, FALSE)
returns FALSE in cell D3. 0 (zero) is the numerical equivalent to FALSE.
Cell D4 returns TRUE, both cells B4 and C4 match cells F4 and G4.
9.3. Using arrays
The array formula above lets you check if all values in cell range B3;B5 are not empty and if all numbers in C3:C5 are above 0 (zero). It returns TRUE if all conditions are TRUE.
Formula in cell B8:
There are many conditions in the above formula and the array formula lets you do this without problems.
To enter an array formula press and hold CTRL + SHIFT simultaneously, then press Enter once. Release all keys.
The formula bar now shows the formula enclosed with curly brackets telling you that you entered the formula successfully. Don't enter the curly brackets yourself.
9.3.1 Explaining formula in cell B8
Step 1 - Check if all values in the array are non-empty
The less than and larger than characters combined lets you check if a value is not equal to another value. The result is a boolean value TRUE or FALSE.
This can be performed to an array of values as well, it returns as many boolean values as there are values in the array.
B3:B5<>""
becomes
{"South America";"Asia";"Middle east"}<>""
and returns {TRUE; TRUE; TRUE}. All values in the cell range are not equal to nothing "".
Step 2 - Check if values are larger than zero
The larger than character lets you check if a value is larger than another value, it also returns a boolean value TRUE or FALSE.
C3:C5>0
becomes
{5; 7; 6}>0
and returns {TRUE; TRUE; TRUE}.
Step 3 - Check if all values are TRUE
The AND function returns a boolean value TRUE or FALSE if all arguments evaluate to TRUE or the numerical equivalent which is one.
AND(B3:B5<>"",C3:C5>0)
becomes
AND({TRUE; TRUE; TRUE}, {TRUE; TRUE; TRUE})
and returns TRUE.
Step 4 - Evaluate IF function
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(AND(B3:B5<>"",C3:C5>0), TRUE, FALSE)
becomes
IF(TRUE, TRUE, FALSE)
and returns TRUE.
10. Function not working
The AND function returns
- #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.
10.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.
10.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:B8 converted to hard-coded value using the F9 key. The AND function requires non-error 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
10.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.
11. Get Excel *.xlsx file
'AND' function examples
Table of Contents Count cells containing text from list Count entries based on date and time Count cells with text […]
Table of Contents Excel monthly calendar - VBA Calendar Drop down lists Headers Calculating dates (formula) Conditional formatting Today Dates […]
This article explains different techniques that filter rows/records that contain a given text string in any of the cell values […]
Functions in 'Logical' category
The AND function function is one of 16 functions in the 'Logical' 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