Written by Allen Wyatt (last updated May 6, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Dimitris has a series of integer values in column A. He would like a way to show the odd values in column B and the even values in column C. He wants the values to be in contiguous cells, with no spaces, and to also be in ascending order. Dimitris wonders if he would need a macro to process his data in this way.
The short answer is that you can, indeed, do this without resorting to a macro. However, if you need to perform this type of processing a lot, you may find it more beneficial to actually use a macro.
First, let's look at the non-macro approaches. You could, if desired, write simple formulas in columns B and C that simply check if the value in column A is odd or even and, if it is appropriate to the column, copy the value over. For instance, you could have the following in column B:
=IF(ISODD(A1),A1,"")
In column C, all you would need to do is replace ISODD with ISEVEN. When you copy these formulas down, then colum B contains only odd values and column C contains only even values. The problem, of course, is that the result doesn't match what Dimitris is looking for: He wants the values in contiguous cells (no blanks) and he wants them in ascending order.
Granted, you can take additional steps to get the desired results—for instance, you could copy the results in columns B and C and paste back values (so the formulas are removed) and then sort the results. This adds additional steps to your work.
There is a way to get a much "cleaner" result by simply using an array formula. Let's assume you're your values are in cells A1:A100. With cells B1:B100 selected, enter the following in the Formula Bar:
=IFERROR(SMALL(IFERROR(INDEX($A$1:$A$100,SMALL( IF(MOD($A$1:$A$100,2)=1,ROW($A$1:$A$100)),ROW( $A1:$A$100))),""),ROW()),"")
Remember that this is all a single formula. Since it is designed to be an array formula, terminate it by entereing Ctrl+Shift+Enter. The result is that you have the odd values in column B, in contiguous cells, in ascending order. To get the even values into column C, first copy B1:B100 to C1:C100. Then, select the range C1:C100. Press F2 to enter edit mode and change the "=1" in the middle of the formula to "=0". Again, terminate the formula by pressing Ctrl+Shift+Enter.
You should note that this formula won't work properly if there are any blanks in the A1:A100 range or if there are any text values in the range. The reason that blanks won't work is because they are treated as a 0 formulaicly, and a 0 is considered even, thus showing up in column C. An alternative formula to determine odd values (column B) is to use the following array formula in cell B1:
=IFERROR(SMALL(IF(MOD($A$1:$A$100,2)>0,$A$1: $A$100,"x"),ROW()),"")
To deal with the potential "blank cell" issue, you could then use the following array formula in cell C1:
=IFERROR(SMALL(IF((MOD($A$1:$A$100,2)=0)*NOT( ISBLANK($A$1:$A$100)),$A$1:$A$100,"x"),ROW()),"")
Copy B1:C1 down as many cells as necessary to get your results.
Earlier I mentioned that you may find it more beneficial to use a macro to process your values. The reason is simple—you can easily get rid of duplicate values (if you need to) and you can ignore blanks and text values. There are any number of ways that such a macro could be developed; I chose an approach that requires you to select which cells you want to process, clears the two columns to the right of those cells, and then puts odds and evens in those columns.
Sub OddsEvens()
Dim rSource As Range
Dim c As Range
Dim sTemp As String
Dim iVal As Integer
Dim bGo As Boolean
Dim sCols As String
Dim vMsg As Variant
Dim lOddCol As Long
Dim iOddPtr As Integer
Dim lEvenCol As Long
Dim iEvenPtr As Integer
Dim iOdds(999) As Integer
Dim iEvens(999) As Integer
Dim J As Integer
Set rSource = Selection
If rSource.Columns.Count = 1 Then
lOddCol = rSource.Column + 1
lEvenCol = rSource.Column + 2
sCols = Chr(lOddCol + 64) & ":"
sCols = sCols & Chr(lEvenCol + 64)
sTemp = "The contents of columns " & sCols
sTemp = sTemp & " will be deleted. Ok to proceed?"
vMsg = MsgBox(sTemp, vbYesNo, "Odds and Evens")
If vMsg = vbYes Then
Application.ScreenUpdating = False
Range(sCols).Clear
iOddPtr = 0
iEvenPtr = 0
For Each c In rSource
bGo = True
' Is the cell empty?
If IsEmpty(c.Value) Then bGo = False
' Does the cell contain non-numeric value?
If Not IsNumeric(c.Value) Then bGo = False
If bGo Then
iVal = c.Value
If Int(iVal / 2) * 2 = iVal Then
' Even number
' Check to see if duplicate
For J = 1 To iEvenPtr
If iEvens(J) = iVal Then bGo = False
Next J
If bGo Then
iEvenPtr = iEvenPtr + 1
iEvens(iEvenPtr) = iVal
End If
Else
'Odd number
' Check to see if duplicate
For J = 1 To iOddPtr
If iOdds(J) = iVal Then bGo = False
Next J
If bGo Then
iOddPtr = iOddPtr + 1
iOdds(iOddPtr) = iVal
End If
End If
End If
Next c
' Stuff values into proper columns
For J = 1 To iOddPtr
Cells(rSource.Row + J - 1, lOddCol) = iOdds(J)
Next J
For J = 1 To iEvenPtr
Cells(rSource.Row + J - 1, lEvenCol) = iEvens(J)
Next J
' Sort values in Odd column
sTemp = Chr(lOddCol + 64) & rSource.Row & ":"
sTemp = sTemp & Chr(lOddCol + 64) & rSource.Row _
+ iOddPtr - 1
Range(sTemp).Select
Selection.Sort key1:=Range(Chr(lOddCol + 64) _
& rSource.Row), Order1:=xlAscending
' Sort values in Even column
sTemp = Chr(lEvenCol + 64) & rSource.Row & ":"
sTemp = sTemp & Chr(lEvenCol + 64) & rSource.Row _
+ iEvenPtr - 1
Range(sTemp).Select
Selection.Sort key1:=Range(Chr(lEvenCol + 64) _
& rSource.Row), Order1:=xlAscending
rSource.Select
Application.ScreenUpdating = True
End If
End If
End Sub
The macro does its work by stuffing values from the selected cells into either of two arrays (iEvens and iOdds). This is done so that the macro can easily check for duplicates in the values. Only if the cell is not empty, it contains a number, and that number is not a duplicate will the value be added to the appropriate array. The values are then stuffed back into the two columns and those values are sorted.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6767) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.
Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!
When sharing workbooks with others, you may find that the macros in those workbooks may not work as you expect. This tip ...
Discover MoreYour worksheets are very often made up of formulas and these formulas are made up of functions. If you ever want to ...
Discover MoreYou can easily add a button to your worksheet that will allow you to run various macros. This tip shows how easy it is.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-05-08 12:04:36
Tomek
I think the easiest way to achieve Dimitris'es goal is to follow Allen's suggestion to split the odd and even values into two colums B an C, then in columns D use the formula =SORT(B1:B100)
and in the column E the formula =SORT(C1:C100).
In newer versions of Excel this will be spilled into array; in older versions you may need to select the ranges D1:D100 and E1:E100 and enter the formula as array formula (Ctrl+Shift+ENTER).
This approach avoids complicated formulas or extensive macros.
As J. Woolley suggested, you can add the UNIQUE function to eliminate duplicates, e.g., =SORT(UNIQUE(B1:B100))
You can hide the helper columns B and C or move them into unused area of the spreadsheet if you wish.
2023-05-06 14:44:04
J. Woolley
Modern versions of Excel can use this formula for odd values (except text or blanks):
=SORT(UNIQUE(FILTER($A$1:$A$100,MOD($A$1:$A$100,2)=1)))
For even values, change MOD(...)=1 to MOD(...)=0.
UNIQUE eliminates duplicates.
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 © 2025 Sharon Parq Associates, Inc.
Comments