Written by Allen Wyatt (last updated April 18, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Clive is a birdwatcher and has over 300 MP3 files of bird sounds. He wants to create an Excel worksheet with a single column in which is listed the actual names of the MP3 files, e.g "cormorant.mp3". He wants to create a hyperlink from each of these 300 or so cells to the physical MP3 file, such that the player will open and play the bird sound. He knows that he can individually insert the hyperlink, but that would obviously be quite tedious. So, he wonders if there is a way to automatically create such a link based on the MP3 file names in the worksheet.
This question actually has two parts: Getting the file names into an Excel worksheet and then creating a link to the MP3 file so the birdsong can be played.
Start by making sure that all the MP3 files are in the same folder on your hard drive. How you can grab a listing of files has been covered in other issues of ExcelTips; you may want to review the ideas of how to do this, found at this ExcelTips page:
http://excelribbon.tips.net/T011144
Once the names are in the worksheet (let's assume they are in column A), you can easily use the HYPERLINK worksheet function to put together the actual link. For example, you could place the following in cell B1:
=HYPERLINK("C:\Documents\Birdsongs\" & A1)
This assumes that the folder in which the songs are located is C:\Documents\Birdsongs\. If the path is actually different, just make the change in the HYPERLINK function.
Once the correct formula is in cell B1, you can then copy it down for however many cells you require to get all the correct hyperlinks.
Of course, you can specify the "display text" to be utilized by the HYPERLINK function. If your birdsong files start with the bird's name and end with .mp3, you could add the display text to the HYPERLINK function in this manner:
=HYPERLINK("C:\Documents\Birdsongs\" & A1, LEFT(A1, LEN(A1) - 4)
This usage simply strips off the last four characters (the period and "mp3") from the file name and then uses that as the display text.
If you want to use a macro approach to actually create hyperlinks (without using the HYPERLINK function), then a good place to start is with the filename-grabbing macro from the tip referred to earlier in this tip. It can be modified to put not only the filenames into the worksheet, but also to create the requisite hyperlinks:
Sub MakeHyperlinks() Dim sPath As String Dim sFile As String Dim iRow As Integer 'specify directory to use - must end in "\" sPath = "C:\Documents\Birdsongs\" iRow = 0 sFile = Dir(sPath) While sFile <> "" iRow = iRow + 1 Sheet1.Cells(iRow,1) = sFile sBird = Left(sFile, Len(sFile)-4) ActiveSheet.Hyperlinks.Add Anchor:=Sheet1.Cells(iRow,1), _ Address:=sPath & sFile, TextToDisplay:=sBird sFile = Dir ' Get next filename Wend End Sub
If you decide to go the macro route, make sure there is nothing in the current worksheet. The macro runs very quickly and wipes out anything that is in the cells to which it writes. When it is done, you end up with the filename in column A and a hyperlink to the MP3 file in column B.
When you click on a hyperlink in the worksheet, Excel launches your Web browser and loads the MP3 file. The browser then plays the file.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13127) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Excel allows you to easily add hyperlinks to your worksheets. If those hyperlinks are suddenly being blocked, it can be ...
Discover MoreMake a reference to a hyperlink in a formula, and you may be surprised that the reference doesn't return an active ...
Discover MoreWhen you establish links between data on a target worksheet and data on a source worksheet, those links are typically ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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