VBA to copy/paste from IF formula without creating an empty string

MarkR3003

New Member
Joined
Aug 11, 2019
Messages
25
I am trying to create a macro that will copy the rows in a 24 row table that contain data (but not the rows with only an IF formula giving "" as the FALSE value) and copy them to another workbook in a table after looking for the next blank row. On running the macro for a second time, it considers the blank rows in the receiving table to have an empty string, so pastes the values below the empty / blank rows rather than in the next row below the actual cell values (numeric, general and date)

Grateful if you could check my VBA and amend to ignore the rows with the empty strings ("")

Dim wsCopy As Worksheet
Dim wsDest As Worksheet
Dim lCopyLastRow As Long
Dim lDestLastRow As Long


'Set variables for copy and destination sheets
Set wsCopy = Workbooks("Book1.xlsm").Worksheets("Database Transfer")
Set wsDest = Workbooks("Book2.xlsx").Worksheets("2021")


'1. Find last used row in the copy range based on data in column A
lCopyLastRow = wsCopy.Cells(wsCopy.Rows.Count, "A").End(xlUp).Row


'2. Find first blank row in the destination range based on data in column A
'Offset property moves down 1 row
lDestLastRow = wsDest.Cells(wsDest.Rows.Count, "A").End(xlUp).Offset(1).Row


'3. Copy & Paste Data
wsCopy.Range("A2:V" & lCopyLastRow).Copy
wsDest.Range("A" & Rows.Count).End(xlUp).Offset(1, 0).PasteSpecial xlValues
Selection.Value = Selection.Value
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
Use this to find the last row with a value
VBA Code:
lCopyLastRow = wsCopy.Range("A:A").Find("*", , xlValues, , xlByRows, xlPrevious, , , False).Row
 
Upvote 0
Solution
Many thanks for the reply which worked brilliantly.

Would you mind if I ask for your advice as how to change the code below so that the macro works in the current workbook rather than named as "Book1" as the file name of the main file (Book1 in the example) changes often with version numbers

Set wsCopy = Workbooks("Book1.xlsm").Worksheets("Database Transfer")
 
Upvote 0
Just replace Workbooks("Book1.xlsm"). with ActiveWorkbook.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
Use this to find the last row with a value
VBA Code:
lCopyLastRow = wsCopy.Range("A:A").Find("*", , xlValues, , xlByRows, xlPrevious, , , False).Row
whats the advantages/difference between the two codes as they both find the last Row with a Value in Column A

lCopyLastRow = wsCopy.Cells(wsCopy.Rows.Count, "A").End(xlUp).Row and
lCopyLastRow = wsCopy.Range("A:A").Find("*", , xlValues, , xlByRows, xlPrevious, , , False).Row

There are loads of ways and was wondering if any had advantages
= wscopy.Range("A99999").End(xlUp).Row
= wscopy.Range("A" & Rows.Count).End(xlUp).Row
= wscopy.Cells(Rows.Count, 1).End(xlUp).Row
 
Upvote 0
they both find the last Row with a Value in Column A
Actually they don't. If you have a formula like =if(Sheet1!A1="","",Sheet1!A1) in col A and that is copied down the sheet, your 1st code will return the last row with the formula, not the last row with a value
 
Upvote 0
Thanks, didn't think of that before.

So in examples below including yours is their any difference between these as they all return same result if last Row contains =""
They return the last value excluding ="" as you mentioned

VBA Code:
lCopyLastRow = wsCOpy.Range("A:A").Find("*", , xlValues, , xlByRows, xlPrevious, , , False).Row
lCopyLastrow = wsCOpy.Range("A:A").Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
lCopyLastRow = wsCOpy.Range("A4:A1000").Find(What:="*", After:=Range("A4"), Lookat:=xlPart, LookIn:=xlValues, SearchOrder:=xlByRows, SearchDirection:=xlPrevious, MatchCase:=False).Row
 
Upvote 0
The 2nd one may not give the same result as you have not specified xlvalues, so it will use either xlformulas or xlvalues depending on the what was used previously.
 
Upvote 0

Forum statistics

Threads
1,212,928
Messages
6,110,734
Members
448,294
Latest member
jmjmjmjmjmjm

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