Written by Allen Wyatt (last updated January 23, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Ron has a worksheet that includes a column containing filenames such as "abcdef." This corresponds to a JPG file ("abcdef.jpg") in the same folder as the worksheet. Ron wonders if there is a way to make Excel automatically display, in the cell just to the right of the filename, a thumbnail of the JPG file.
If, by "automatic," you mean that the image appears whenever a filename is placed into the cell, that is possible, but it is not necessarily the best way to go. Why? Because working with graphics files can take a huge number of resources in your workbook, and as you add more and more filenames, the amount of data that needs to be shuttled around can be huge.
A better approach is to develop a macro that will look at whatever cells you have selected (those cells should contain the filenames) and then insert the thumbnails to the right of those selected cells. Here's an example:
Sub Insert_Pics_By_Filename() Dim Source As Range Dim c As Range Dim s As Shape Dim sThumbSize As Single Dim sPath As String Dim sHeight As Single Dim sLeft As Single Dim xTop As Single ' xTop instead of sTop because sTop is a keyword Dim sTemp As String sThumbSize = 0.75 ' Picture will be 75% of row height Set Source = Selection sPath = ActiveWorkbook.Path & "\" ' Check the filenames in the cells, first For Each c In Source.Cells sTemp = c.Value If Not (sTemp Like "*.jpg") Then c.Select MsgBox "Can't work with the filename:" & vbCr & vbCr & sTemp & " in cell " & c.Address Exit Sub End If Next c ' Delete all existing pictures For Each s In ActiveSheet.Shapes If s.Type = msoLinkedPicture Then s.Delete End If Next s ' Insert the pictures For Each c In Source.Cells With c sHeight = .RowHeight * sThumbSize sLeft = .Offset(0, 1).Left + 5 ' Put 5 pixels from cell left xTop = .Top + 5 ' Put 5 pixels from cell top sTemp = .Value With ActiveSheet.Pictures.Insert(sPath & sTemp) With .ShapeRange .LockAspectRatio = msoTrue .Height = sHeight End With .Left = sLeft .Top = xTop .Placement = 1 .PrintObject = True End With End With Next c End Sub
The macro creates a thumbnail that is 75% of the height of the row and inserts that thumbnail to the right of the selected cells. If one of the selected cells doesn't have ".jpg" as part of the filename, then it will stop and tell you that there is an error with the name.
The macro isn't terribly robust, in that you could easily crash it. For instance, if the row heights is quite small, then the thumbnails will be very small—and if they are too small, then there could be a fatal error in inserting the thumbnail. You should be aware, as well, that the macro also deletes all pictures in the worksheet before it inserts the thumbnails. That way you don't run the risk of getting duplicate images inserted. If you want the macro to delete just a portion of the images, then you'll need to do a good deal of reworking the macro to detect and affect just the subset of images desired.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9983) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Excel doesn't just work with numbers and text. You can also add graphics objects to your worksheets, and then use Excel's ...
Discover MoreA common way of representing data is to use a Venn diagram. Unfortunately, Excel doesn't have a precise way of creating ...
Discover MoreNeed to make sure that someone cannot delete a graphic in a worksheet? The ability to protect the graphic depends on ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-01-29 07:35:55
Barry Brookshire
Thank you Mr. Harold Druss!!!
This works PERFECTLY!!!
2021-01-28 06:32:10
Harold Druss
Replace "Set Source = Selection" with:
========================================
Dim lRow As Long
'Find the last non-blank cell in column A(1)
lRow = Cells(Rows.Count, 1).End(xlUp).Row
Set Source = Range("A2:A" & lRow)
========================================
2021-01-27 09:20:15
Barry Brookshire
I'm new to VBA & by no means an expert.
I see great potential in using this code for adding pics in our routine safety audits, but the auditors are not "Excel savvy".
How can I make the code determine the last filename is reached in the column and make that the range to use to add in the pics so that you don't have to "pre-select" the range of filenames before executing the code?
1,000,000,000,000 thanks in advance!!!
2021-01-23 04:58:23
Ron
Thank you very much Allen!
I will use the given solution and let you know if it worked for me
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments