VBA Copy report and paste at bottom of another sheet

mamyers64

New Member
Joined
Feb 11, 2016
Messages
17
I have a report named rptJR which contains an external query. I need some code that will copy and paste special values + formats to the bottom of another sheet called Jobs. There are two blank rows in between each report pasted into the Jobs sheets. The Report also has blank cells in the header rows. The code below will find the first empty row at the bottom of all reports but it will not paste values + format in that cell. I get an error on the "Range("1Row").Select" line.


VBA Code:
Sub Macro5()
'
' Copy & Past Report to Jobs sheet
'


'
'Finds the last non-blank cell on a sheet/range.


Dim lRow As String
Dim lCol As Long


1Row = "A" & Cells.Find(What:="*", _
After:=Range("A1"), _
LookAt:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByRows, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Row + 1


'Copy and Paste report into
Application.Goto Reference:="rptJR"
Selection.Copy
Sheets("Jobs").Select
ActiveWindow.SmallScroll Down:=3
Range("1Row").Select
Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
:=False, Transpose:=False
Selection.PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
SkipBlanks:=False, Transpose:=False
End Sub
 
Last edited by a moderator:

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Try
Code:
Sub Macro5()
'
' Copy & Past Report to Jobs sheet
'


'
'Finds the last non-blank cell on a sheet/range.


Dim lRow As Long
Dim lCol As Long


lRow = Cells.Find(What:="*", _
   After:=Range("A1"), _
   LookAt:=xlPart, _
   lookIn:=xlFormulas, _
   SearchOrder:=xlByRows, _
   SearchDirection:=xlPrevious, _
   MatchCase:=False).Row + 1


'Copy and Paste report into
Application.Goto Reference:="rptJR"
Selection.Copy
Sheets("Jobs").Select
   With Range("A" & lRow)
      .PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
         :=False, Transpose:=False
      .PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
         SkipBlanks:=False, Transpose:=False
   End With
End Sub
 
Upvote 0
Solution
Glad to help & thanks for the feedback
 
Upvote 0
I spoke too soon. The code works perfectly when I run it from inside the VBA editor but when I run the macro from inside the worksheet it errors out on this piece of code:

.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
:=False, Transpose:=False
 
Upvote 0
Ok, try making the change in red
Rich (BB code):
lRow = sheets("Jobs").Cells.Find(What:="*", _
   After:=Range("A1"), _
   LookAt:=xlPart, _
   lookIn:=xlFormulas, _
   SearchOrder:=xlByRows, _
   SearchDirection:=xlPrevious, _
   MatchCase:=False).Row + 1
 
Last edited by a moderator:
Upvote 0
Final Result:

VBA Code:
Sub PasteToJobs()
'
' Copy & Past Report to Jobs sheet
'




'
'Finds the last non-blank cell on a sheet/range.




Dim lRow As Long
Dim lCol As Long




lRow = Sheets("Jobs").Cells.Find(What:="*", _
   After:=Range("A1"), _
   LookAt:=xlPart, _
   LookIn:=xlFormulas, _
   SearchOrder:=xlByRows, _
   SearchDirection:=xlPrevious, _
   MatchCase:=False).Row + 1




'Copy and Paste report into Jobs sheet
Application.Goto Reference:="rptJR"
Selection.Copy
Sheets("Jobs").Select
   With Range("A" & lRow)
      .PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
         :=False, Transpose:=False
      .PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, _
         SkipBlanks:=False, Transpose:=False
   End With
End Sub
 
Last edited by a moderator:
Upvote 0

Forum statistics

Threads
1,214,636
Messages
6,120,666
Members
448,977
Latest member
moonlight6

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