Written by Allen Wyatt (last updated January 16, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Robert has a series of numbers in column A that range from 1 to 100. He would like to extract only those values between 65 and 100, inclusive, and place them in column B. He wonders if there is a way to do that easily.
The short answer is that there is a very easy way to do it, provided you don't mind sorting the list of numbers. Follow these steps:
That's it; you've now got the desired cells into column B. If you simply wanted to copy the cells, then in step 5 you could have pressed Ctrl+C instead.
If you need to keep the values in column A in their original order (minus the values you want to move), you can do it by using column B as a "place retainer" column. To the right of the first value in column A, put the vaue 1. Then, below that in column B put a 2, then a 3, and so on, until each value in column A has a corresponding value in column B that indicates the numbers location. Then, follow these steps:
At this point the values in columns A and B reflect their original order, from when they were all in column A.
Another way to move the cells is to use the filtering capabilities of Excel. Follow these steps:
Figure 1. The Custom AutoFilter dialog box.
You could also use formulas in column B to pull out the values that are within the desired range. An easy way to do this is to place this formula in cell B1:
=IF(AND(A1>=65, A1<=100),A1,"")
Copy the formula down as far as necessary in column B and you end up with any values in the range of 65 to 100, inclusive, being "copied" into column B. If the value is outside this range, then the cell in column B is left empty.
Assuming that you don't want any empty cells in column B, then you could use an array formula to grab the values. If your values are in the range A1:A500, place the following in cell B1:
=IFERROR(INDEX(A$1:A$500,SMALL(IF(A$1:A$500>=65,ROW($1:$500)),ROW())),"")
Enter it using Ctrl+Shift+Enter, and then copy the formula down as far as you'd like.
There are, of course, macro-based solutions you can use. These are helpful if you need to perform this task quite a bit with data that you retrieve from an outside source. The following is a simple example of a macro you could use:
Sub ExtractValues1() Dim x As Integer x = 1 For Each cell In Selection If cell.Value >= 65 And cell.Value <= 100 Then Cells(x, 2) = cell.Value x = x + 1 End If Next cell End Sub
You use the macro by selecting the cells you want evaluated in column A and then running it. It looks at each cell and copies the value to column B. The original value in column A is left unchanged.
For more flexibility you could rely on asking the user for the lower and upper values, as shown in this macro:
Sub ExtractValues2() Dim iLowVal As Integer Dim iHighVal As Integer iLowVal = InputBox("Lowest value wanted?") iHighVal = InputBox("Highest value wanted?") For Each cell In Range("A:A") If cell.Value <= iHighVal And cell.Value >= iLowVal Then ActiveCell.Value = cell.Value ActiveCell.Offset(1, 0).Activate End If Next End Sub
Before you run the macro, select the cell at the top of the range where you want the extracted values placed. Nothing in column A is affected; only the values between the lower and upper range are copied to the new location.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13397) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
When you undo actions within Excel, those steps you undo may affect the multiple workbooks in which you've been working. ...
Discover MoreDo you need to know how many words are in a range of cells? Excel provides no intrinsic way to count the words, but you ...
Discover MoreWhen entering many negative values in a worksheet, you could save time if you didn't need to enter the minus sign for ...
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