Separating Evens and Odds

by Allen Wyatt
(last updated June 17, 2017)

2

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, and 2016.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Searching for Non-Black Text

Searching for text having (or not having) specific formatting is generally pretty easy. It is more difficult to search for ...

Discover More

Generating Unique Numbers for Worksheets

You may need to automatically generate unique numbers when you create new worksheets in a workbook. Here's a couple of easy ...

Discover More

Spelling Out Page Numbers

If your document is more than a couple of pages long, adding page numbers is a nice finishing touch. If you want, you can ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Calculating the Distance between the Top of the Window and Row 1

Normally Excel positions a UserForm in the center of your screen. You may want to position the form elsewhere, more specific ...

Discover More

Editing Macros

Even if you do nothing but record macros, sooner or later you will have a need to edit what you record. Here's how to get to ...

Discover More

Quickly Dumping Array Contents

Variable arrays are used quite often in macros. If you use an array once in your macro and then need to reuse it for ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 3 + 8?

2017-06-19 04:33:32

DaveS

@ Supin R.
Alternatively, replace Row() with Row(A1).


2017-06-19 04:14:38

Supin R.

The array formula won't work right if they don't begin in row 1. For example, if the values and formula are in cells A3:C102 instead of A1:C100, the values returned in column B or C will start with the third lowest not the lowest since the first formula is in row 3 not in row 1. To correct this in the last 2 array formula in the tip, replace "ROW()" with "ROW()-2" in case that the formula always start in row 3; or "ROW()-ROW(B$2) by referencing the row before the first formula; or "ROW()-ROW($B$3)+1 by referencing the first row of formula (and to prevent errors in case there is no rows before the first formula).


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.