Ignoring Formulas When Searching For Next Empty Cell

ExcelAtEverything

Active Member
Joined
Jan 30, 2021
Messages
351
Office Version
  1. 2019
Platform
  1. Windows
Hello! The following was created to find the next empty cell within a range in column B, and then paste in info which was copied from O6:P6. The only problem is that it's not working correctly because I have cells in column B which contain formulas (fitted with an IFERROR prefix to keep some cells empty when there is no info to fill them). How can I edit this to ignore cells containing formulas in column B when looking for the next empty?

Sub AddExtraStoreToLocMasterList() '
' AddExtraStoreToLocMasterList Macro
' This macro copies O6:P6 to cipboard, then finds first blank cell in column B Loc Master List range, and the paste specials there.
'
Range("O6:P6").Select
Selection.Copy
Range("B4").Select
ActiveCell.End(xlDown).Offset(1, 0).Select
Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
:=False, Transpose:=False
Range("O6:P6").Select
Application.CutCopyMode = False
Selection.ClearContents
Range("O6").Select
End Sub
 
Although the OP has decided to go in a different direction, those who might visit this thread looking for a solution to the originally posed question might find this non-looping macro (which I believe works the way the OP wanted) to be of interest...
VBA Code:
Sub AddExtraStoreToLocMasterList()
  On Error Resume Next
  Range("B4", Cells(Rows.Count, "B")).SpecialCells(xlBlanks).Areas(1)(1).Resize(, 2) = Range("O6:P6").Value
  If Err.Number Then Range("B4").End(xlDown).Offset(1).Resize(, 2) = Range("O6:P6").Value
  On Error GoTo 0
  Range("O6:P6").ClearContents
  Range("O6:P6").Select
End Sub
 
Last edited:
Upvote 0
Solution

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Thx Rick! I've already changed the sheet around a bit, or I would certainly try that out.
 
Upvote 0
So funny!!! Rick, I swear to you... ever since I sent that last reply, I have been sitting here thinking about whether or not I should or If I'm better off as is now.
LMAO! I think it's too far removed at this point, and I think I prefer it without at this point. You could always take a stab at my latest issue/post!
 
Upvote 0
You could always change the sheet back. :devilish:
Tried to plug it in as I had it before so that I can verify it works and give you the checkmark, but it errors saying...
1615439517984.png

Not sure why, Macros are enabled, cell numbers match... So I can't say whether its a problem w/ the code or something on my end.
 
Upvote 0
Never mind... I just noticed you are using a Mac... I am using a PC. It worked for me, but maybe there is something about a Mac that is balking at the code.
 
Upvote 0
Never mind... I just noticed you are using a Mac... I am using a PC. It worked for me, but maybe there is something about a Mac that is balking at the code.
Rick, I'm on my PC laptop. In fact I'm removing the MAC from my profile, as I never use my mac for Excel as it turns out.
 
Upvote 0
I wonder why it didn't work for you. Are the blanks (the ones without formulas in them) true blanks (no spaces in them)?
 
Upvote 0
No Rick, that was part of the issue. While the cells 'appear' blank, there are formulas in them.
 
Upvote 0

Forum statistics

Threads
1,213,563
Messages
6,114,332
Members
448,566
Latest member
Nickdozaj

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top