MIKEBIZ,
1. What version of Excel, and, Windows are you using?
2. Are you using a PC or a Mac?
Here is another macro solution for you to consider. And, if the number is not found in row 1, you will get a message that the number was not found, and, the macro will terminate without an error.
You can change the raw data worksheet name in the macro.
Sample raw data:
Excel 2007 |
---|
|
---|
| A | B | C | D | E | F | G | H | I | J | K | L | M | N |
---|
1 | 1 | 11 | 59 | 35 | 33 | 46 | 12 | 18 | | | | | | |
---|
2 | | | | | | | | | | | | | | |
---|
3 | | 60 | < what number to add | | | | | | | | | | | |
---|
4 | | 59 | < after which number | | | | | | | | | | | |
---|
5 | | | | | | | | | | | | | | |
---|
|
---|
After the macro:
Excel 2007 |
---|
|
---|
| A | B | C | D | E | F | G | H | I | J | K | L | M | N |
---|
1 | 1 | 11 | 59 | 60 | 35 | 33 | 46 | 12 | 18 | | | | | |
---|
2 | | | | | | | | | | | | | | |
---|
3 | | 60 | < what number to add | | | | | | | | | | | |
---|
4 | | 59 | < after which number | | | | | | | | | | | |
---|
5 | | | | | | | | | | | | | | |
---|
|
---|
Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).
1. Copy the below code
2. Open your NEW workbook
3. Press the keys
ALT +
F11 to open the Visual Basic Editor
4. Press the keys
ALT +
I to activate the Insert menu
5. Press
M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys
ALT +
Q to exit the Editor, and return to Excel
8. To run the macro from Excel press
ALT +
F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.
Code:
Sub MIKEBIZ()
' hiker95, 08/23/2015, ME877731
Dim c As Range, n As Long
Application.ScreenUpdating = False
With Sheets("Sheet1") '<-- you can change the sheet name here
If Not [B3] = vbEmpty And Not [B4] = vbEmpty Then
n = Application.CountIf(.Rows(1), [B4])
If n = 0 Then
Application.ScreenUpdating = True
MsgBox ("B4's value '" & [B4] & "' is not in row 1 - macro terminated!")
Exit Sub
ElseIf n > 0 Then
If [A1] = [B4] Then
[B1].Insert Shift:=xlShiftToRight
[B1] = [B4]
Else
Set c = .Rows(1).Find([B4], LookAt:=xlWhole)
.Cells(c.Row, c.Column + 1).Insert Shift:=xlShiftToRight
.Cells(c.Row, c.Column + 1).Value = [B3]
End If
End If
Else
Application.ScreenUpdating = True
MsgBox ("Cells 'B3' and 'B4' are empty - macro terminated!")
Exit Sub
End If
End With
Application.ScreenUpdating = True
End Sub
Before you use the macro with
Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension
.xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
Then run the
MIKEBIZ macro.