Do you want to lookup in any column and return the result? Something like this:

In this article, learn how to write necessary Excel formulas to get the result.
Data Setup for looking up in any column
You need to set up your data in below structure. One column with the data you want to get and multiple columns with potential lookup value. For example, team name in column C, member names in columns D:J, as depicted below.

Lookup formula:
Let’s say we want to lookup “Leonard”, who is in the tea “Geeky Group”. Here is the formula.
=XLOOKUP(1,BYROW(D5:J13,LAMBDA(row,COUNTIFS(row,"Leonard"))),C5:C13)
'notes:
'D5:J13 contains team member names
'C5:C13 contains team names
'this will return #N/A if none of the teams contain lookup value - ie LeonardHow does this formula work?
To understand how this lookup in any column formula is working, we need to first understand a few Excel concepts.
- BYROW: This function let’s you define logic or operations that apply consistently for each row of the data. As we want to look in each row of team members and see if any of them is “Leonard”, BYROW is perfect for this operation.
- LAMBDA: We can use Excel’s LAMBDA functions to create custom logic. As we need to check each row of the data to see if any of the members are “Leonard”, I created a LAMBDA to do that operation. LAMBDA(row, COUNTIFS(row, “Leonard”)) will return the count of “Leonard” in the input variable row
So now that you have the basic concepts ready, let’s understand the lookup in any column function. Here is the formula again.
=XLOOKUP(1,BYROW(D5:J13,LAMBDA(row,COUNTIFS(row,"Leonard"))),C5:C13)
'notes:
'D5:J13 contains team member names
'C5:C13 contains team names
'this will return #N/A if none of the teams contain lookup value - ie Leonard- BYROW(D5:J13,LAMBDA(row,COUNTIFS(row,”Leonard”))): This formula portion tells us how many times “Leonard” appeared in each row of the data. It will be 0 if the team doesn’t contain lookup value and 1(or more) if the team contains the lookup value. For our sample data, this would be {0;0;0;0;0;1;0;0;0}
- XLOOKUP(1, BYROW(…), C5:C13): Now that we know which team has the lookup value (Leonard), we just lookup for 1 (count) in the BYROW output and return the corresponding team name from the column C.
What if there are multiple matching values?
By default XLOOKUP returns the first matching value whenever we have multiple matches. If you want to see all team names for a given person name (for example Amy is in two teams – “Geeky Group” and “99 Not Out”.

In this case, we can use FILTER() function instead of XLOOKUP.
Using FILTER function to return all matching values
Here is the formula to see all team names for a given person.
=FILTER(C5:C13,BYROW(D5:J13="Amy",OR))
'notes:
'D5:J13 contains team member names
'C5:C13 contains team names
'Here we are using an advanced variation of BYROW that applies OR operation on every row of comparison directly. The end result would be a bunch of TRUE or FALSE values, TRUE for teams that contain "Amy" and FALSE for rest of the rows.This formula uses an advanced variation of the BYROW by doing a comparison directly and applying OR operation on each row of comparison. The result of BYROW would be an array of TRUE or FALSE values. TRUE for rows which contain Amy and FALSE for the rest.
When FILTER(C5:C13 …) sees this array of TRUE/FALSE values, it would return the matching items from C5:C13 for all TRUE values.
In this case, the output is shown below.

Further reading:
If you want to understand how the inner parts of this formula are working, refer to below articles / videos.
- How to use XLOOKUP function in Excel
- BYROW explained with examples
- What is LAMBDA function in Excel
- How to use FILTER function in Excel
- FILTER function in Excel – Video
Limitations of both formulas
Both of the above approaches (XLOOKUP and FILTER) only work with Excel 365 as BYROW is only available in that version of Excel. If you are using an older version of Excel (such as 2024, 2019 or 2016) you can’t use these approaches.
Alternative formula for older version of Excel
There is no alternative for the FILTER() approach as older versions of Excel are not capable of spilling values. But there is an alternative to XLOOKUP() approach of returning the first matching value by looking up any column.
Here is the formula:
=INDEX($C$5:$C$13,MATCH(1, MMULT((D5:J13="Leonard")*1,TRANSPOSE(COLUMN(D5:J13)^0)),0))
'notes:
'D5:J13 contains team member names
'C5:C13 contains team namesUsing MMULT to mimic BYROW operation
Most of the above formula is easy to understand, but the bit with MMULT is the confusing part. So let me explain. Here is the MMULT portion: MMULT((D5:J13=”Leonard”)*1,TRANSPOSE(COLUMN(D5:J13)^0))
- (D5:J13=”Leonard”) checks every cell of the team member data and returns a bunch of TRUE or FALSE values. TRUE when the cell value is “Leonard” and FALSE otherwise. This is how that output looks like:

- (D5:J13=”Leonard”)*1 turns this boolean array into a bunch of 0s & 1s (0 = false and 1 = true). So the output at this point would be:

- COLUMN(D5:J13) would return the the column numbers for columns D to J. This would be an array of {4,5,6,7,8,9,10}
- TRANSPOSE(COLUMN(D5:J13) turns these numbers into a row-wise array. So the net result at this point is {4;5;6;7;8;9;10}
- TRANSPOSE(COLUMN(D5:J13)^0 takes all these numbers and makes them 1s as any number raised to the power of 0 would be. We just need a row-wise array of 1s same size as the number of columns in the team member array. So this is a long-winded way of getting there as older versions of Excel don’t have SEQUENCE formula. At this stage, our second part of MMULT operation has this array: {1;1;1;1;1;1;1}
- Now, MMULT just multiplies these two matrices. Here they are again:

- When the matrix multiplication is done, we end up with a vertical (row-wise) array of 0s and 1s. 0 when the row doesn’t contain the lookup value (Leonard) and 1 otherwise. The result of this multiplication is:

Let’s put everything together
So now that we know how the MMULT magic is working, let’s put all the pieces together.
=INDEX($C$5:$C$13,MATCH(1, MMULT((D5:J13="Leonard")*1,TRANSPOSE(COLUMN(D5:J13)^0)),0))
'notes:
'D5:J13 contains team member names
'C5:C13 contains team namesINDEX($C$5:$C$13,MATCH(1, MMULT(…), 0)) simply looks for a 1 in the MMULT result and returns the corresponding value from range C5:C13.
Further reading on older Excel formulas:
Please refer to below pages for further learning on these formula techniques.
- INDEX + MATCH formula in Excel – explanation
- SUMPRODUCT explained
- How to use boolean operations with arrays in Excel
- MMULT examples
Example Workbook: Lookup in any column
If you need a practice file to understand these formulas better, download it here.
In conclusion
While Excel’s lookup functions (XLOOKUP, VLOOKUP, FILTER, INDEX+MATCH) are great, they all suffer from one nagging limitation. They can only lookup in one place at a time (ie one column or row). But most of the time, our business data is not so tidy. We get data that can span multiple columns. In such cases, using the BYROW() to process one row at a time and then applying lookup or filter logic is a great alternative.
Moreover, if your data is structured vertically (ie team members are listed in rows instead of columns), we can use the same approach with BYCOL function. It applies the logic by column.
The BY functions (BYROW and BYCOL) are great addition to Excel and should be part of every analyst’s toolkit. Using them solves many tricky data problems easily.












40 Responses to “Looking up when the data won’t co-operate (case study)”
Nice Trick.. Clever use of cell references
Here is a formula I tried to create:
=SUMPRODUCT(((NOT(ISERROR(SEARCH(L5,B4:H14))))*1),(B5:H15))
It takes care of Caveat #1 (can handle text), but Caveat #2 remains.
In situations like this, I will often use VBA to restructure the data (2 columns: dates and values) on to a new worksheet. I can then use this 'clean' source for data analysis (formula or pivot table).
=SUMPRODUCT(((NOT(ISERROR(SEARCH(L5,B4:H14))))*1),(B5:H15)) and complex formulae in general are all very well but when you come back to them in a few weeks / months time, it is not at all easy to see what they do and what the limitations are.
Hi Chandoo,
I had used this type of cell ref. various times while calculating average.
But for the situation here try below formula . Note this is an array formula and must be confirmed with Ctrl+Shift+Enter.
=SMALL(IF(MMULT((L5=B4:H14)*IF(ISNUMBER(B5:H15),B5:H15),{1;1;1;1;1;1;1}),MMULT((L5=B4:H14)*IF(ISNUMBER(B5:H15),B5:H15),{1;1;1;1;1;1;1})),1)
Regards,
Hi, I think Using SEARCH in here will create a problem say there is a text like SUN and another text SUNLIGHT both result will be added by SUMPRODUCT.
Regards,
Array option.
=SUM(IF(MOD(ROW(B4:B14),2)=MOD(ROW(B4),2),IF(B4:H14=L5,B5:H15)))
Regards
@Elias,
Nice approach.
Although not requested - the formula I suggested closes all possibilities.
Criteria: _____ Value to retrieve:
Date__________ Numeric
Date__________Textual
Textual________Numeric
Textual________Textual
While your formula copes with only the 3 first combinations.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
Sorry but I don’t understand your point. I believe the challenge was to return the summary of a given date. What is your really volatile formula doing that mine is not?
Regards
@Elias,
I didn't say that the challenge differs from what you just mentioned/aimed to nor that your formula doesn't provide the requested result.
Please read my previous comment again and focus on the last combination (TEXT / TEXT).
I, myself, always try to provide a global Formula that is capable to handle all sorts of data.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
I see your point, but you are missing the below points if you are trying to cover all sorts of data.
What happened if the lookup value does not exist?
Do you want the first, second, summary, concatenation of the values if the look value is repeated?
See they are too many possibilities to be cover with just one formula.
Regards
1) The range: B4:H15 was named: RNG.
2) The following Array Formula was "retrieved from my sleeve" and I hope it can be shorten.
3) The formula seems to take care of BOTH(!) caveats.
-------------------------------------------------------------------------------
=OFFSET(INDIRECT(ADDRESS(SMALL(IF(RNG=L5,ROW(RNG),""),1),MOD(SMALL(IF(RNG=L5,(ROW(RNG))+COLUMN(RNG)/10),1),1)*10)),1,)
-------------------------------------------------------------------------------
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
Check what happened with your result if you type 41927 in D5.
Regards
Correct. Didn't predict that.
Will find time to work something out.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Elias,
Let's hope the following Array Formula "closes all open doors".
Again - it has nothing to do with your formula which works fine as long as the 3 first mentioned combinations are concerned.
-------------------------------------------------------------------------------
=INDEX(RNG,LARGE(IF(RNG=L5,MOD(ROW(RNG)-1,2)*(ROW(RNG)),""),1)-2,(MOD(SMALL(IF(RNG=L5,(ROW(RNG))+COLUMN(RNG)/10),1),1)*10)-1)
-------------------------------------------------------------------------------
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
Ok, if you insist. The following will cover all the scenarios you listed. However, I’ll never recommend/use such of formula.
Defined names:
rDat = $B$4:$H$15
rRow =ROW(rDat)-MIN(ROW(rDat))+1
rCol =COLUMN(rDat)-MIN(COLUMN(rDat))+1
rInc =MOD(rRow,2)=MOD(MIN(rRow),2)
L6=INDEX(rDat,MAX(IF(rInc,IF(rDat=L5,rRow)))+1,MAX(IF(rInc,IF(rDat=L5,rCol))))
Array Enter
Regards
@Michael,
unfortunately, your array formula still seems to return wrong results (eg 3-Nov).
If data are organized like in the example, ie. looks like a calendar, the INDEX formula seems quite simple:
=INDEX($B$4:$H$15,ROUNDDOWN((L5-B4)/7,0)*2+2,MOD((L5-B4),7)+1)
Yours is effectively the same as what I just came up with, and I believe this is the optimal answer to this particular problem.
My solution, before I saw yours:
=OFFSET(B5,QUOTIENT(L5-B4,7)*2,MOD(L5-B4,7))
OFFSET will work for an arbitrary list size, but INDEX might be easier to read.
QUOTIENT does the round and division in a single step.
If there's an improvement over Elias's solution then I for one can't see it.
Perhaps a non-CSE version which would also mean that only two references (B4:H14 and B5:H15), as opposed to three (B4, B4:B14 and and B5:H15), would require manually amending should the data range change, i.e.:
=SUMPRODUCT((ISEVEN(ROW(B4:H14)-MIN(ROW(B4:H14)))*(B4:H14=L5)*B5:H15))
I suppose we could make it a single, uniform range reference:
=SUMPRODUCT((ISEVEN(ROW(B4:H14)-MIN(ROW(B4:H14)))*(B4:H14=L5)*OFFSET(B4:H14,1,,,)))
which might be more appropriate should we e.g. wish to use a Defined Name for our range, i.e.:
=SUMPRODUCT((ISEVEN(ROW(Rng)-MIN(ROW(Rng)))*(Rng=L5)*OFFSET(Rng,1,,,)))
though whether that compensates for the extra, volatile function call is something to be debated.
Regards
I have tried something and then my Excel workbooks got shut down. Maybe that was too much?
Anyway here is what I've tried:
=SUMPRODUCT(INDEX(B5:H15;IF(ISEVEN(ROW(B5:H15));ROW(B5:B15)-ROW(B5)+1);{1\2\3\4\5\6\7}))
Guess that was wrong? Would this approach work anyway?
Looking forward to learn something from you Excel Experts.
Sorry, I haven't took notice of XOR LX's answer. I guess that's kind of what I was looking for.
@Michael Avidan
As it stands that is not a very rigorous construction.
You say "I, myself, always try to provide a global Formula that is capable to handle all sorts of data", which is a wonderful philosophy, but isn't it at least as important that we ensure that our formulas are independent of the row and column references of the data range in question, so that, should that range change, we do not have to re-work our solution?
What happens with your formula, for example, if RNG is instead re-located one row down, from B4:H15 to B5:H16?
When a formula is reliant upon the addition/subtraction of certain constants within the formula, which themselves are necessarily dependent upon the specific rows/columns in which the data lies at any given time (e.g. the -1 in MOD(ROW(RNG)-1,2)), then that formula is not a very flexible one.
Hence the reason for my choice of a slightly longer construction:
ROW(B4:H14)-MIN(ROW(B4:H14))
which ensures that this part of the calculation is not dependent upon the precise location of the data range within the worksheet, and so will give correct answers even if that range is re-located.
Regards
{=OFFSET(B4,MAX((B4:H15=L5)*ISODD(ROW(1:12))*ROW(1:12)),MAX((B4:H15=L5)*ISODD(ROW(1:12))*COLUMN(A:G))-1)}
Non-array formula:
=INDEX(B4:H15,SUMPRODUCT((B4:H15=L5)*(ROW(B4:H15)-ROW(B4)+1)*ISODD(ROW(B4:H15)-ROW(B4)+1))+1,SUMPRODUCT((B4:H15=L5)*(COLUMN(B4:H15)-COLUMN(B4)+1)*ISODD(ROW(B4:H15)-ROW(B4)+1)))
Using one range (B4:H15), one reference (B4), one lookup value (L5) and no INDIRECT or OFFSET.
My trial with defined names:
DateRange
=$B$4:$H$4,$B$6:$H$6,$B$8:$H$8,$B$10:$H$10,$B$12:$H$12,$B$14:$H$14
Position
=RANK('lookup problem'!$L$5,DateRange,1)
L6
=OFFSET(B4,ROUNDUP(Position/7,0)*2- 1,IF(MOD(Position,7)=0,6,MOD(Position,7)-1))
I'd probably just run with something like:
=SUMPRODUCT((B4:H14=L5)*(MOD(ROW(B4:H14),2)=MOD(ROW(B4),2))*B5:H15)
...which is basically the same as Elias' but without the IFs
The opposite of elegant but it works...
=INDEX(B4:H15,IFERROR(MATCH(L5,B4:B14,0),0)+IFERROR(MATCH(L5,C4:C14,0),0)+IFERROR(MATCH(L5,D4:D14,0),0)+IFERROR(MATCH(L5,E4:E14,0),0)+IFERROR(MATCH(L5,F4:F14,0),0)+IFERROR(MATCH(L5,G4:G14,0),0)+IFERROR(MATCH(L5,H4:H14,0),0)+1,IFERROR(MATCH(L5,B4:H4,0),0)+IFERROR(MATCH(L5,B6:H6,0),0)+IFERROR(MATCH(L5,B8:H8,0),0)+IFERROR(MATCH(L5,B10:H10,0),0)+IFERROR(MATCH(L5,B12:H12,0),0)+IFERROR(MATCH(L5,B14:H14,0),0))
=INDEX(B4:H15,
IFERROR(MATCH(L5,B4:B14,0),0)+
IFERROR(MATCH(L5,C4:C14,0),0)+
IFERROR(MATCH(L5,D4:D14,0),0)+
IFERROR(MATCH(L5,E4:E14,0),0)+
IFERROR(MATCH(L5,F4:F14,0),0)+
IFERROR(MATCH(L5,G4:G14,0),0)+
IFERROR(MATCH(L5,H4:H14,0),0)+1,
IFERROR(MATCH(L5,B4:H4,0),0)+
IFERROR(MATCH(L5,B6:H6,0),0)+
IFERROR(MATCH(L5,B8:H8,0),0)+
IFERROR(MATCH(L5,B10:H10,0),0)+
IFERROR(MATCH(L5,B12:H12,0),0)+
IFERROR(MATCH(L5,B14:H14,0),0))
Named Range
rownum = SUMPRODUCT(('lookup problem'!$B$4:$H$14='lookup problem'!$L$5)*ROW('lookup problem'!$B$4:$H$14)*ISEVEN(ROW('lookup problem'!$B$4:$H$14)))
Formula
=OFFSET($A$1,rownum,MATCH(L5,INDIRECT("$B"&rownum&":$H"&rownum),0))
How about SUM(IF(B4:H14=L5,B5:H15)) with array..it should work
Sorry, Chandoo, you can't find stuff this way in every possible scenario.
What if 2014-10-01 sales would equal 41.927 ? Which is serial number for 2014-10-15 ? SUMIF would fail to retrive correct answer. And your example data suggest that such number is possible in your table.
It's better not to search through dates and numbers at the same time.
If I'd solve a problem like this, it'd reformat table first so I get one column with dates and the other with numbers.
In this case, formula to form date column would be:
=INDIRECT(ADDRESS((INT((ROW()-4)/COUNT($B$4:$H$4))+1)*2+2;MOD(ROW()-4;COUNT($B$4:$H$4))+2;4;1))
and numbers would be the same formula with sight adjustment (+3 instead of +2 at the end of first argument):
=INDIRECT(ADDRESS((INT((ROW()-4)/COUNT($B$4:$H$4))+1)*2+3;MOD(ROW()-4;COUNT($B$4:$H$4))+2;4;1))
And now you got two columns that you can safely use for searching!
Oops, sorry, you actually mentioned that it doesn't work if number=date! I missed that part 🙁
={OFFSET(A1,SUM((B4:H14=L5)*ROW((B4:H14))),SUM((B4:H14=L5)*COLUMN((B4:H14)))-1)}
Works for all data... the solution I got for indirect looks little lengthy
I want to count last 20 records of a person, whose marks is greater than 2 and grade "manager". ....
Assume A1 has got names (James, John...etc...)
A2 "Manager"
A3 "2"
Someone please reply
I want to count last 20 records of a person, whose marks is greater than "2" and grade "Manager"
Assume A1 "geroge" A2 "Michael" A3 "George" etc...name can found anywhere in the rows
B1 "Manager" B2" clerk"
C1 "2" C2, "4"
please reply
Simplest I can come up with. No limitations for either 1 or 2. This does assume dates are an ordered list with 7 per row, and 2 rows per set. Assuming this is always true this will work for an arbitrary long list of dates.
=OFFSET(B5,QUOTIENT($L$5-$B$4,7)*2,MOD($L$5-$B$4,7))
@Marc,
Nice approach - however, as there are no "Negative Dates" - try:
=OFFSET(B5,INT(L5-B4)/7)*2,MOD(L5-B4,7))
——————————————————————————-
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
=OFFSET(B4,ROUNDUP((L5-41911+1)/7,0)*2-1,MOD(L5-41911,7))
B4 has been used as reference cell for OFFSET().
FOR ROWS:
ROUNDUP(....,0) gives the integer value of a division. In case of presence of a remainder, ROUNDUP will add 1 to the Quotient.
As opposed to ROUNDUP(), the INT() or QUOTIENT() functions eliminate the remainder.
41911 = 01-Sept-2014, the first date in the data.
*2 has been used because there are 2 columns per set of data.
/7 has been used because there are 7 columns per set of data.
For columns
MOD(L5-41911,7))
Vijaykumar Shetye,
Panaji, Goa, India
This is how i did it
{=INDEX(B4:H15, MAX((L5=B4:H15)*ROW(B4:H15))-2, MAX((L5=B4:H15)*COLUMN(B4:H15))-1 )}
Here's my solution:
=INDEX(B4:H15,MATCH(1,MMULT(--(B4:H15=L5),TRANSPOSE(COLUMN(B4:H15)^0)),0)+1,MATCH(1,MMULT(TRANSPOSE(--(B4:H15=L5)),ROW(B4:H15)^0),0))
Sorry, forgot to mention Ctrl Shift Enter is needed.