×

VBA Code To Alphabetize Cell Text While Excluding Certain Short Words

By Chris Newman •  Updated: 06/10/16 •  5 min read
VBA Code To Alphabetize Cell Text While Excluding Certain Short Words

The following VBA code was inspired by a YouTube video I came across where Excel MVP Oz Du Soleil and Kevin Lehrbass provided formula solutions for ways to alphabetize titles while at the same time ignoring words like “A” and “The” during the sorting.

Alphabetizing Titles in Excel while ignoring A, An and The: Kevin Lehrbass & Oz Challenge

What This VBA Code Does

This VBA code will take a range of cells with text and sort it alphabetically while ignoring any number of words (such as “An” and “The”). The following is an example of what the code will do with a given list of titles:

VBA code will take a range of cells with text and sort it alphabetically while ignoring any number of words (such as "An" and "The")

Here is the VBA Code

Sub AlphabetizeCells_ExcludeWords()
'PURPOSE: Alphabetize a range of cells while excluding certain words from the text values
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault

Dim Rng As Range
Dim TmpRng
Dim fndList As Variant
Dim x As Integer

'Input List of Words to Exclude
  fndList = Array("A ", "An ", "The ", "In ", "To ")

'Get Range of Cells
  On Error GoTo Cancel
    Set Rng = Application.InputBox("Please Select Cell Range To Alphabetize", Type:=8)
  On Error GoTo 0
  
'Optimize Code
  Application.ScreenUpdating = False
  
'Insert New Column to Right of Data
  Rng.Offset(0, 1).EntireColumn.Insert Shift:=xlToRight, CopyOrigin:=xlFormatFromLeftOrAbove
  Set TmpRng = Rng.Offset(0, 1)

'Copy/Paste Values data set into new temporary column
  Rng.Copy
  TmpRng.PasteSpecial Paste:=xlPasteValues
  Application.CutCopyMode = False
    
'Find/Replace
  For x = LBound(fndList) To UBound(fndList)
    TmpRng.Replace What:=fndList(x), Replacement:="", _
      LookAt:=xlPart, SearchOrder:=xlByRows, MatchCase:=False, _
      SearchFormat:=False, ReplaceFormat:=False
  Next x

'Sort Data Alphabetically
  ActiveSheet.Sort.SortFields.Clear
  ActiveSheet.Sort.SortFields.Add Key:=TmpRng, _
    SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
  
  'Apply Sort
    With ActiveSheet.Sort
      .SetRange Rng.Resize(Rng.Rows.Count, 2)
      .Header = xlGuess
      .MatchCase = False
      .Orientation = xlTopToBottom
      .SortMethod = xlPinYin
      .Apply
    End With
  
'Delete Temporary Column
  TmpRng.EntireColumn.Delete Shift:=xlToLeft
  
Cancel:

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!

Keep Learning

Chris Newman

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.

[FREE Training] 10 Amazing Excel Efficiency Tricks. Why Don't People Know These?!

X