Summary

To apply AND and OR logic to an array using the AND function and the OR function, you can use the MAP function. In the example shown, the formula in cell E5 is:

=MAP(data[Color],data[Qty],LAMBDA(a,b,AND(OR(a="red",a="blue"),b>10)))

where data is an Excel Table in the range B5:C15.

Generic formula

=MAP(array1,array2,LAMBDA(a,b,AND(OR(a="red",a="blue"),b>10)))

Explanation 

In this example, the goal is to apply AND and OR logic to an array using the AND function and the OR function. The challenge is that the AND function and the OR function both aggregate values to a single result. This means you can't use them in an array operation where the goal is to return more than one result. One workaround to this limitation is to use the MAP function, as explained below. All data is in an Excel Table named data in the range B5:C15.

AND and OR limitations

In this example, we want to test each row in the table with the following logic:  Color is "Red" OR "Blue" AND Qty > 10. For each row in the table, we want a TRUE or FALSE result. If we try to use a formula like this:

=AND(OR(data[Color]="red",data[Color]="blue"),data[Qty]>10)

The formula will fail because the AND function and the OR function both aggregate values to a single result.

MAP function

One solution to implementing the logic above is to use the MAP function. The MAP function "maps" a custom LAMBDA function to each value in a supplied array. The LAMBDA is applied to each value, and the result from MAP is an array of results with the same dimensions as the original array. The MAP function is useful when you want to process each item in an array individually, but as an array operation that yields an array result. 

In this example, we supply the MAP function with two arrays: data[Color], and data[Qty]:

=MAP(data[Color],data[Qty],

Next, we need supply a LAMBDA function that implements the logic we need:

=MAP(data[Color],data[Qty],LAMBDA(a,b,AND(OR(a="red",a="blue"),b>10)))

Notice that inside the LAMBDA function, data[Color] becomes "a", and data[Qty] becomes "b". These names are arbitrary and you can use any valid name you like . The arrays provided to the MAP function are named by the parameters in the LAMBDA in the order that they appear.

The MAP function works through each value in data[Color] and data[Qty] and implements the logic created by the AND and OR functions. Since there are 11 rows in the table, the result is an array of 11 TRUE and FALSE values like this:

{FALSE;TRUE;FALSE;TRUE;FALSE;FALSE;FALSE;TRUE;FALSE;FALSE;FALSE}

These values are returned to cell E5 and spill into the range E5:E15.

Counting results

The formula in cell G5 shows a practical application of the MAP formula explained above:

=SUM(MAP(data[Color],data[Qty],LAMBDA(a,b,--AND(OR(a="red",a="blue"),b>10))))

Here, the goal is to count all TRUE results from MAP. To do that, we add a double negative (--) before the AND function to convert TRUE and FALSE values to 1s and 0s, then we nest the entire formula inside the SUM function. The MAP function returns the numeric array to SUM:

=SUM({0;1;0;1;0;0;0;1;0;0;0}) // returns 3

The SUM function then returns a final result of 3.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.