Explanation
In this example, we need to construct logic that filters data to include:
account begins with "x" AND region is "east", and month is NOT April.
The filtering logic of this formula (the include argument) is created by chaining together three expressions that use boolean logic on arrays in the data. The first expression uses the LEFT function to test if Account begins with "x":
LEFT(B5:B16)="x" // account begins with "x"
The result is an array of TRUE FALSE values like this:
{TRUE;FALSE;TRUE;TRUE;TRUE;FALSE;FALSE;FALSE;TRUE;TRUE;FALSE;TRUE}
The second expression tests if Region is "east" with the equal to (=) operator:
C5:C16="east" // region is east
The result is another array:
{FALSE;FALSE;TRUE;TRUE;TRUE;FALSE;TRUE;FALSE;FALSE;TRUE;FALSE;TRUE}
The third expression uses the MONTH function with the NOT function to test if the month is not April:
NOT(MONTH(D5:D16)=4) // month is not april
which yields:
{FALSE;FALSE;FALSE;TRUE;TRUE;TRUE;TRUE;TRUE;TRUE;TRUE;TRUE;TRUE}
Note that the NOT function reverses the result from the MONTH expression.
All three arrays are multiplied together. The math operation coerces the TRUE and FALSE values to 1s and 0s, so at this point we can visualize the include argument like this:
{1;0;1;1;1;0;0;0;1;1;0;1}*
{0;0;1;1;1;0;1;0;0;1;0;1}*
{0;0;0;1;1;1;1;1;1;1;1;1}
Boolean multiplication corresponds to the logical function AND, so the final result is a single array like this:
{0;0;0;1;1;0;0;0;0;1;0;1}
The FILTER function uses this array to filter the data, and returns the four rows that correspond with the 1s in the array.
Extending criteria
The expressions used to create the include argument in filter can be extended as needed to handle even more complex filters. For example, to further filter data to include only rows where amount > 10000, you could use a formula like this:
=FILTER(B5:E16,(LEFT(B5:B16)="x")*(C5:C16="east")*NOT(MONTH(D5:D16)=4)*(E5:E16>10000))