Forum Discussion
#SPILL! Error when doing VLOOKUP?
- Jul 31, 2019
Hi Jennifer Corcoran ,
This is likely because your VLOOKUP is looking up multiple values in the first argument (the red text below).
=VLOOKUP(A:A,B:B,1,FALSE)
By looking up A:A you are asking Excel to lookup a million cells. In the past this worked because Excel didn't know how to lookup multiple values, so it threw all but one away. This behaviour was called "implicit intersection". With the introduction of Dynamic Arrays, Excel now supports looking up multiple values and no longer does implicit intersection silently. If there isn't enough space to return the values you will see the #SPILL error.
To modify your formula to return just a single value, you can use one of the following techniques:
1. Modify you formula to use the new implicit intersection operator @ to select one lookup value. =VLOOKUP(@A:A,B:B,1,FALSE)
2. Simply reference a single cell and copy down. =VLOOKUP(A2,B:B,1,FALSE)
Both work but my preferred option is 2 as it is the simplest.
Regards, Joe [Excel Team]
Hi Jennifer Corcoran ,
This is likely because your VLOOKUP is looking up multiple values in the first argument (the red text below).
=VLOOKUP(A:A,B:B,1,FALSE)
By looking up A:A you are asking Excel to lookup a million cells. In the past this worked because Excel didn't know how to lookup multiple values, so it threw all but one away. This behaviour was called "implicit intersection". With the introduction of Dynamic Arrays, Excel now supports looking up multiple values and no longer does implicit intersection silently. If there isn't enough space to return the values you will see the #SPILL error.
To modify your formula to return just a single value, you can use one of the following techniques:
1. Modify you formula to use the new implicit intersection operator @ to select one lookup value. =VLOOKUP(@A:A,B:B,1,FALSE)
2. Simply reference a single cell and copy down. =VLOOKUP(A2,B:B,1,FALSE)
Both work but my preferred option is 2 as it is the simplest.
Regards, Joe [Excel Team]
- JTalcApr 12, 2020Copper Contributor
Hi Joe and Brad.
I am getting a spill error with the function
=VLOOKUP ([Color Number], colors, 4,FALSE)
Where should I put the @ (implicit intersection operator) to stop the #SPILL ERROR
I am looking up an item's color number in the colors table to get the year that color was retired if applicable, in the 4th column of the table. the function returns 0 if the retired cell in the lookup table is blank
- Brad YundtApr 12, 2020MVP
I really wish that you had posted a workbook.
I tried to imagine what your layout looked like, and decided you might have a four column named range called colors and a table named Table1 with a column header label of Color Number. I then created a formula on the same row as data in the table, but not part of the table. That's where I got a #SPILL error value.
The fix was to use this formula:
=VLOOKUP(Table1[@[Color Number]], colors, 4,FALSE)
- JTalcApr 12, 2020Copper Contributor
Hi Brad,
thank you very much, I will ask my tutee in excel to try this. see 2 workbooks from me and her, she got the error, I did not.
- KwaseMar 12, 2020Copper ContributorThis still doesn't work for me. I have the various years of birth for over 16k data which I have put in a year e.g. 1958 -1964 and so on. I am using the ranges as my table array. My challenge is I select only one cell, it returns a wrong range and for the others it gives me #N/A. I select all the data in my table array, it returns as #SPILL.
What am I doing wrong?- Brad YundtMar 12, 2020MVP
Post a file and show the type of results you want. That way, an appropriate formula can be suggested.
Brad Yundt