VBA To Add A Prefix to Selected Cells

What This VBA Code Does
In my day job, I often have to add a prefix to thousands of ID numbers in order to perform lookups across different data sets. I finally had enough of manually inserting temporary formulas to add the prefix, so I began to write a macro that could do this with a click of the button.
I thought the solution was rather straightforward, just loop through each cell and concatenate my prefix with the current cell’s value. However, due to the extremely large amount of cells this code needed to loop through (and the data was also in an Excel table). My first stab at automating this was extremely slow. That’s when I needed to think a little bit more creatively and come up with a solution that did not rely on looping…
VBA Code:
Use Replace Function (Fast Solution)
Originally, I posted I solution utilizing the Evaluate function, however, Rick Rothstein provided a better solution in the comments section of this post, so I am using this as the fast solution. Rick suggested creatively using the Replace function to add the prefix to everything in the selection (including blank cells). A second Replace function is called to remove the prefix from cells that were originally blank. Thank you Rick for an awesome solution!
Sub AddPrefix()
'PURPOSE: Concatenate a prefix to all values in the cell selection
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
'Contributor: Rick Rothstein
Dim Prefix As String
'Input(s)
Prefix = "ID"
'Optimize Code
Application.ScreenUpdating = False
'Add Prefix to Selection (No Looping)
Selection = Application.Replace(Selection, 1, 0, Prefix)
'Remove Prefix for any originally Blank Cells in Selection
Selection.Replace Prefix, "", xlWhole, , , , False, False
End Sub
Use a For Loop (Slow Solution)
If you would like to opt for a slower but more commonplace solution, below is an example showing how you can utilize a For Loop to add a prefix to each cell in a selection.
Sub AddPrefix()
'PURPOSE: Concatenate a prefix to all values in the cell selection
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim Prefix As String
Dim Cell As Range
'Input(s)
Prefix = "ID"
'Optimize Code
Application.ScreenUpdating = False
'Add Prefix to Selection (Looping)
For Each Cell In Selection.Cells
If Cell.Value <> "" Then Cell.Value = Prefix & Cell.Value
Next Cell
End Sub
Using VBA Code Found On The Internet
Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.
Getting Started Automating Excel
Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.
Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!
How Do I Modify This To Fit My Specific Needs?
Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it!
I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).
I wish you the best of luck and I hope this tutorial gets you heading in the right direction!
After 10+ years of creating macros and developing add-ins, I've compiled all the hacks I wish I had known years ago!

Keep Learning
Chris Newman
Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.