Copy and Paste to last row

canyon

New Member
Joined
Jan 5, 2022
Messages
24
Office Version
  1. 2019
Platform
  1. Windows
In the midst of trying to automate a report and the final step is to take the 2 workbooks and copy all the data (excluding the header) from WB1 to the first empty row of WB2.

The issue I'm having is that it when it copies from WB1 it will paste about 173 rows below the last row of WB2... not sure what I am doing wrong however here is my code.

VBA Code:
Sub test()

Dim copywb As Worksheet
Dim pastewb As Worksheet
Dim LastRow As Long
Dim copywblastrow As Long
Dim pastelastrow As Long

Workbooks("WB1").Worksheets("salesorders_1").Activate
Workbooks("WB2.xlsm").Worksheets("sheet1").Activate


Set copywb = Workbooks("WB1.xlsm").Worksheets("salesorders_1")
Set pastewb = Workbooks("WB2.xlsm").Worksheets("sheet1")

copywblastrow = copywb.Cells(copywb.Rows.Count, "C").End(xlUp).Row
pastelastrow = pastewb.Cells(pastewb.Rows.Count, "A").End(xlUp).Offset(1).Row

copywb.range("A2:H" & copywblastrow).copy pastewb.range("A" & pastelastrow)


End Sub
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Do the 2 message boxes below give you the same results back?

VBA Code:
Sub test()

Dim copywb As Worksheet
Dim pastewb As Worksheet
Dim LastRow As Long
Dim copywblastrow As Long
Dim pastelastrow As Long
Dim pastelastrow2 As Long

Workbooks("WB1").Worksheets("salesorders_1").Activate
Workbooks("WB2.xlsm").Worksheets("sheet1").Activate


Set copywb = Workbooks("WB1.xlsm").Worksheets("salesorders_1")
Set pastewb = Workbooks("WB2.xlsm").Worksheets("sheet1")


pastelastrow = pastewb.Cells(pastewb.Rows.Count, "A").End(xlUp).Offset(1).Row
MsgBox "pastelastrow is " & pastelastrow

pastelastrow2 = pastewb.Columns(1).Find("*", , xlValues, , xlByRows, xlPrevious).Offset(1).Row
MsgBox "pastelastrow2 is " & pastelastrow2



End Sub
 
Upvote 0
Solution
Do the 2 message boxes below give you the same results back?

VBA Code:
Sub test()

Dim copywb As Worksheet
Dim pastewb As Worksheet
Dim LastRow As Long
Dim copywblastrow As Long
Dim pastelastrow As Long
Dim pastelastrow2 As Long

Workbooks("WB1").Worksheets("salesorders_1").Activate
Workbooks("WB2.xlsm").Worksheets("sheet1").Activate


Set copywb = Workbooks("WB1.xlsm").Worksheets("salesorders_1")
Set pastewb = Workbooks("WB2.xlsm").Worksheets("sheet1")


pastelastrow = pastewb.Cells(pastewb.Rows.Count, "A").End(xlUp).Offset(1).Row
MsgBox "pastelastrow is " & pastelastrow

pastelastrow2 = pastewb.Columns(1).Find("*", , xlValues, , xlByRows, xlPrevious).Offset(1).Row
MsgBox "pastelastrow2 is " & pastelastrow2



End Sub

Hey... sorry late reply, weekend and all. It's giving me the last row of each sheet, it just isn't executing the paste from WB1 to WB2.
 
Upvote 0
Please explain exactly what is/isn't happening as this statement...
It's giving me the last row of each sheet, it just isn't executing the paste from WB1 to WB2.

doesn't tally with what you stated in your first post

The issue I'm having is that it when it copies from WB1 it will paste about 173 rows below the last row of WB2.
 
Upvote 0
Please explain exactly what is/isn't happening as this statement...


doesn't tally with what you stated in your first post


Sorry...my intent is to copy everything from WB1 into the first empty row of WB2.

With my old code it was copying and pasting, but it would paste about 174 rows below my data in WB2.

With the code you worked it gives me the last row but doesn't copy/paste.

Hope that clears it up!
 
Upvote 0
Your code looked ok in principle, so @MARK858 was trying to get you to compare your code's last row against an alternative method using the Find function.
You should have seen 2 messages boxes one for each of the 2 methods, yours first and then his Find option.
Did they both show the same last row number ?

In theory if the Find method gave a different result and was correct you could replace your "pastelastrow =" line with his.
It does most likely mean that you have formulas in column A that return "" and you would need to be happy to overwrite those with your copy.
 
Upvote 0
Your code looked ok in principle, so @MARK858 was trying to get you to compare your code's last row against an alternative method using the Find function.
You should have seen 2 messages boxes one for each of the 2 methods, yours first and then his Find option.
Did they both show the same last row number ?

In theory if the Find method gave a different result and was correct you could replace your "pastelastrow =" line with his.
It does most likely mean that you have formulas in column A that return "" and you would need to be happy to overwrite those with your copy.

Makes more sense now... when I ran the above code I got the same number. Based on your advice I was able to get the desired result using @MARK858's code.

Finished code:

VBA Code:
Sub test()

Dim copywb As Worksheet
Dim pastewb As Worksheet
Dim LastRow As Long
Dim copywblastrow As Long
Dim pastelastrow As Long
Dim pastelastrow2 As Long

Workbooks("WB1.xlsm").Worksheets("salesorders_1").Activate
Workbooks("WB2.xlsx").Worksheets("sheet1").Activate


Set copywb = Workbooks("WB1.xlsm").Worksheets("salesorders_1")
Set pastewb = Workbooks("WB2.xlsx").Worksheets("sheet1")


copywblastrow = copywb.Cells(copywb.Rows.Count, "C").End(xlUp).Row

'pastelastrow = pastewb.Cells(pastewb.Rows.Count, "A").End(xlUp).Offset(1).Row
'MsgBox "pastelastrow is " & pastelastrow

pastelastrow2 = pastewb.Columns(1).Find("*", , xlValues, , xlByRows, xlPrevious).Offset(1).Row

'MsgBox "pastelastrow2 is " & pastelastrow2


copywb.range("A2:H" & copywblastrow).copy pastewb.range("A" & pastelastrow2)

End Sub
 
Upvote 0

Forum statistics

Threads
1,223,276
Messages
6,171,139
Members
452,381
Latest member
Nova88

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