Explanation
Working from the inside out, the logical criteria used in this formula is this expression:
--(names=G4)
where names is the named range C4:E7. This generates a TRUE / FALSE result for every value in the data, and the double negative coerces the TRUE and FALSE values to 1 and 0 to yield an array like this:
{0,0,0;1,0,0;0,0,0;0,0,0}
This array is 4 rows by 3 columns, matching the structure of "names". A second array is created with this expression:
TRANSPOSE(COLUMN(names)^0))
The COLUMN function is used to create a numeric array with 3 columns and 1 row, and TRANSPOSE converts this array to 1 column and 3 rows. Raising the result to the power of zero simply converts all numbers in the array to 1. The MMULT function is then used to perform matrix multiplication:
MMULT({0,0,0;1,0,0;0,0,0;0,0,0},{1;1;1})
and the result goes into the MATCH function as the array argument, with 1 as the lookup value:
MATCH(1,{0;1;0;0},0)
The MATCH function returns the position of the first match, which corresponds to the first matching row meeting supplied criteria. This is fed into INDEX as the row number, with the named range "groups" as the array:
=INDEX(groups,2)
Finally, INDEX returns "Bear", the group Adam belongs to.
Literal "contains" criteria
To check for specific text values instead of an exact match, you can use the ISNUMBER and SEARCH functions together. For example, to match cells that contain "apple" you can use:
=ISNUMBER(SEARCH("apple",data))
This formula is explained here.