Copy formula from cell above

jayped

Board Regular
Joined
Mar 20, 2019
Messages
54
hi, I have the VBA code which copies from worksheet to another. Rows are also inserted in sh2 where sh1 has greater than 15 rows beginning row 7. Row 6 has a formula in columns E and I and I would like to be able to copy the formula into rows that were inserted by the macro. How can I add this function into the macro below? Unfortunately I do not understand some of the threads I've come across on this topic.

Sub t()
Dim wb As Workbook, sh1 As Worksheet, sh2 As Worksheet, lr As Long, fName As String, cell As Range
fName = Application.GetOpenFilename("Excel Files(*.xls*), *.xls*")


Set sh2 = ActiveSheet
Set wb = Workbooks.Open(fName)
Set sh1 = wb.Sheets(1)
lr = sh1.Cells.Find("*", , xlValues, xlPart, xlByRows, xlPrevious).Row
With sh1
.UsedRange.AutoFilter 2, "<>" & "PAYMENT"
cnt = .UsedRange.Resize(, 1).SpecialCells(xlCellTypeVisible).Count - lr + 7
If cnt <= 15 Then
.Range("B9:B" & lr).Copy
sh2.Cells(7, 1).PasteSpecial xlPasteValues
.Range("C9:C" & lr).Copy
sh2.Cells(7, 2).PasteSpecial xlPasteValues
.Range("D9:D" & lr).Copy
sh2.Cells(7, 7).PasteSpecial xlPasteValues
.AutoFilterMode = False

Else
sh2.Rows(7).Resize(cnt - 15).EntireRow.Insert
.Range("B9:B" & lr).Copy
sh2.Cells(7, 1).PasteSpecial xlPasteValues
.Range("C9:C" & lr).Copy
sh2.Cells(7, 2).PasteSpecial xlPasteValues
.Range("D9:D" & lr).Copy
sh2.Cells(7, 7).PasteSpecial xlPasteValues

.AutoFilterMode = False
End If
End With

wb.Close False
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
You can Do it with Autofill. Example:
VBA Code:
Range("E6").Autofill Destination:=Range("E6:E" & Cnt - 14)
Range("I6").Autofill Destination:=Range("I6:I" & Cnt - 14)
 
Upvote 0
Try this:
VBA Code:
Sub tRev()
    Dim wb As Workbook, sh1 As Worksheet, sh2 As Worksheet, lr As Long, fName As String 'Redundant variable deleted
    fName = Application.GetOpenFilename("Excel Files(*.xls*), *.xls*")
    Set sh2 = ActiveSheet
    Set wb = Workbooks.Open(fName)
    Set sh1 = wb.Sheets(1)
    lr = sh1.Cells.Find("*", , xlValues, xlPart, xlByRows, xlPrevious).Row

    With sh1
        .UsedRange.AutoFilter 2, "<>" & "PAYMENT"
        cnt = .UsedRange.Resize(, 1).SpecialCells(xlCellTypeVisible).Count - lr + 7
        If cnt <= 15 Then
            .Range("B9:B" & lr).Copy
            sh2.Cells(7, 1).PasteSpecial xlPasteValues
            .Range("C9:C" & lr).Copy
            sh2.Cells(7, 2).PasteSpecial xlPasteValues
            .Range("D9:D" & lr).Copy
            sh2.Cells(7, 7).PasteSpecial xlPasteValues
            .AutoFilterMode = False
        Else
            sh2.Rows(7).Resize(cnt - 15).EntireRow.Insert
            .Range("B9:B" & lr).Copy
            sh2.Cells(7, 1).PasteSpecial xlPasteValues
            .Range("C9:C" & lr).Copy
            sh2.Cells(7, 2).PasteSpecial xlPasteValues
            .Range("D9:D" & lr).Copy
            sh2.Cells(7, 7).PasteSpecial xlPasteValues
            .Cells(6, "E").Copy 'Added
            sh2.Cells(6, "E").PasteSpecial xlPasteFormulas 'Added
            .Cells(6, "I").Copy 'Added
            sh2.Cells(6, "I").PasteSpecial xlPasteFormulas 'Added
            .AutoFilterMode = False
        End If
    End With
    
    wb.Close False
End Sub
 
Upvote 0
Solution
Thanks goes to both Maabadi and Kanadaaa. I was able to combine your solutions to accomplish what I needed:

sh2.Cells(6, "E").Copy
sh2.Range("E6:E" & Cnt - 15 + 6).PasteSpecial xlPasteFormulas
sh2.Cells(6, "I").Copy
sh2.Range("I6:I" & Cnt - 15 + 6).PasteSpecial xlPasteFormulas
 
Upvote 0

Forum statistics

Threads
1,214,875
Messages
6,122,044
Members
449,063
Latest member
ak94

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