Forum Discussion

Jennifer Corcoran's avatar
Jennifer Corcoran
Former Employee
Nov 09, 2018
Solved

#SPILL! Error when doing VLOOKUP?

I just updated my Office 365 (Mac) with the latest Excel updates yesterday and for some reason can no longer do a standard vlookup formula. The results in the cell where I"m trying to do lookup, return with "#SPILL!" I've tried doing the lookup several times and no luck. Does anyone know what this response means? 

  • 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]

     

27 Replies

  • MatthewWillis's avatar
    MatthewWillis
    Copper Contributor

    How do we turn off the Dynamic Arrays - I can't make them work for me and I don't want them.  They are confusing everything and will lead to dangerous errors being made.  365 is a disaster.

  • 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]

     

    • JTalc's avatar
      JTalc
      Copper Contributor

      JoeMcDaid 

      Brad Yundt 

      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

       

      • 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)

         

    • Kwase's avatar
      Kwase
      Copper Contributor
      This 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?
      • Kwase 

        Post a file and show the type of results you want. That way, an appropriate formula can be suggested.

        Brad Yundt

  • I am having the same issue but on a PC, recent update. I was not able to use the below recommendation, as it did not provide any useful guidance. Help, I use VLook-up all the time and this is creating work stoppage!! Please let me know if you have learned of any other suggestions to fix the Spill error.
    Thank you!
    • utkarsh0103's avatar
      utkarsh0103
      Copper Contributor

      Ljohnson329 

      Experiencing the same issue. And not able to find the reason behind that and also not able to get the solution anywhere.

      • Brad_Yundt's avatar
        Brad_Yundt
        MVP

        utkarsh0103 

        Please post a workbook that demonstrates the problem. If the problem is reproduced at my end (I have multiple versions of Mac and Windows Excel), I can either suggest a workaround & explanation, or else report it to Microsoft developers as a bug.

Resources