Invalid Reference Error on INDEX MATCH to image

KDavidP1987

Board Regular
Joined
Mar 6, 2018
Messages
51
Greetings all!


I am a new member to MrExcel Discussion Boards, but have relied on your wisdom for years. Unfortunately, I came across an issue that I cannot find a solution to, and I have tried searching everywhere for an explanation. I will try explaining as best as I can, please let me know if you have any follow-up questions.

THE PROBLEM:
I am trying to use an INDEX MATCH function to pull an agent's profile picture into an Coaching sheet / dashboard, but when I reach the final step listed in every post/video I receive this error


:eek: Microsoft Excel: Reference is NOT valid!


STEPS USED:

  1. Created dropdown list of agent's names using data validation
    • I can confirm this works, because my other INDEX match function successfully pulls their monthly metrics correctly
  2. Increase height of rows where agent's name and other info is listed, inserted default profile picture for testing within each agents Employee Picture Column.
    • Ensured pictures do NOT extend beyond borders of the cell!
  3. Create INDEX MATCH formula to reference the agent's name with the column their profile pic is in.
    • =INDEX(EmployeeRoles[[FootPrints Name]:[Employee Picture]],MATCH(AgentName,EmployeeRoles[FootPrints Name],0),6)
      • Links are relative (uses cell title from column header), data tables in workbook are formatted as tables
      • Tested to ensure it worked, by placing a test value in the cell. Confirmed it pulled the test value!
  4. Move INDEX MATCH formula into Name Manager, titled ProfilePic, refers to is the formula
  5. Created image to be changed, on the coaching sheet
    • Tried the following methods of this, based on different methods found in forums/videos
      • Created BitMap image (from Insert tab -> Object)
      • Copied the cell underneath a profile picture, then pasted special as linked Picture
      • Copied an agent's profile picture and pasted it into the coaching sheet
  6. Click the image (various types attempted), change formula to name used in naming manager =ProfilePic
  7. :eek: ERROR MESSAGE = Microsoft Excel: Reference is NOT valid! :eek:

Side notes:

  • As I mentioned, I can put text into the cell where the image should be pulled, and the text is successfully extracted by the INDEX MATCH formula
  • I can make the picture reference other cells successfully, including linking it manually to the cells where the pictures are located. It only throws the error when I try referencing the named formula (from Naming Manager)

Here are some links to posts/videos of what I'm trying to accomplish:





I cannot figure out what I'm doing wrong. I know the INDEX MATCH formula works, and I know the picture will successfully change to a statically/manually assigned cell. I've tried inserting pictures different ways. I've confirmed the correct Name used from Name Manager. It's like it refuses to accept the link to the Name Manager formula, but I just don't know why...


Any ideas, please?


Sincerely,
Kristopher
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
In the comments below the Youtube video someone says they reckon they found the solution to "Reference Not Valid" though I havent delved any deeper into this
 
Upvote 0
Thank you for pointing that out, I missed it! Maybe it is an issue with using the named relative named ranges to reference the cells, perhaps Naming Manager doesn't like that... I have yet to test it out, but I will as soon as I can and let y'all know!

Roderick de Leeuw
7 months ago (edited)
I believe I found the answer to the issue of 'reference not valid'. After a lot of frustration I noticed that when I tried to connect the image to the 'name' (=....) the formula in the name manager had changed.

> So use the $$ signs or press F4 on the cells in the formula you upload there and I was good to go.

Good to know:
- Naming my ranges broke my formula, so I switched back to 'hard values'
- Pasting in various ways (paste special) didn't make any difference after I fixed the before mentioned

Hope this helps!
 
Upvote 0
Still shows up first in google to this problem so adding my answer. Table references seem to result in "reference isn't valid" error when entering dynamic image reference.
it seems this only works with absolute sheet references.
In the named cell reference:
works:
=INDEX(Sheet1!$F$3:$F$4,MATCH(Sheet1!$M$4,Sheet1!$E$3:$E$4,0))
does not work
=INDEX(Table1,MATCH(Sheet1!$M$4,Table1[a],0),2)

The first named range displays the image, the second gives a reference error when entered into the image formula.
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,751
Members
448,989
Latest member
mariah3

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top