Problem executing VBA code

sofas

Well-known Member
Joined
Sep 11, 2022
Messages
559
Office Version
  1. 2021
  2. 2019
Platform
  1. Windows
I am trying to transfer data from Sheet 1 to Sheet 2, paste every 10 separate rows, calculate the sum of the value of column M for every 10 rows in row 11, and write the word TOTAL under column J, inserting 5 empty rows between each range and the other.

VBA Code:
[CODE] WSdest.Range("A" & fin) = WSdata.Range("A" & x)

 WSdest.Range("B" & fin) = WSdata.Range("B" & x)

 WSdest.Range("C" & fin) = WSdata.Range("C" & x)


 *



'Is it possible to shorten only these rows instead of
'writing the names of the 16 columns that currently exist?[/CODE]
 
Last edited:

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
VBA Code:
Option Explicit
Option Base 1

Sub CopyRows()
Dim wb As Workbook, wsData As Worksheet, wsDest As Worksheet, cRng As Range, lRow As Long, i As Long, y As Long, x As Long
Application.ScreenUpdating = False
Set wb = ThisWorkbook: Set wsData = wb.Sheets("Sheet1"): Set wsDest = wb.Sheets("Sheet2")
lRow = wsData.Rows.End(xlDown).Row
Set cRng = wsData.Range("A1:P" & lRow)
i = 1
y = 4
x = 3
cRng.Rows(1).Copy wsDest.Cells(1, 1)
cRng.Rows(2).Copy wsDest.Cells(3, 1)
Application.CutCopyMode = False
Do Until x > lRow
    Do Until i > 10
        If IsEmpty(cRng.Range("A" & x)) Then Exit Do
        cRng.Rows(x).Copy wsDest.Cells(y, 1)
        Application.CutCopyMode = False
        i = i + 1: y = y + 1: x = x + 1
    Loop
    wsDest.Range("J" & y) = "Total": wsDest.Cells(y, "M").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)"
    wsDest.Cells(y, "O").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)": wsDest.Cells(y, "P").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)"
    wsDest.Range("J" & y & ":P" & y).Interior.Color = 65535
    i = 1
    y = y + 2
    cRng.Rows(1).Copy wsDest.Cells(y, 1)
    y = y + 2
    cRng.Rows(2).Copy wsDest.Cells(y, 1)
    Application.CutCopyMode = False
    y = y + 1
Loop
Application.ScreenUpdating = True
End Sub
 
Upvote 1
Solution
Option Explicit
Option Base 1

Sub CopyRows()
Dim wb As Workbook, wsData As Worksheet, wsDest As Worksheet, cRng As Range, lRow As Long, i As Long, y As Long, x As Long
Application.ScreenUpdating = False
Set wb = ThisWorkbook: Set wsData = wb.Sheets("Sheet1"): Set wsDest = wb.Sheets("Sheet2")
lRow = wsData.Rows.End(xlDown).Row
Set cRng = wsData.Range("A1:P" & lRow)
i = 1
y = 4
x = 3
cRng.Rows(1).Copy wsDest.Cells(1, 1)
cRng.Rows(2).Copy wsDest.Cells(3, 1)
Application.CutCopyMode = False
Do Until x > lRow
Do Until i > 10
If IsEmpty(cRng.Range("A" & x)) Then Exit Do
cRng.Rows(x).Copy wsDest.Cells(y, 1)
Application.CutCopyMode = False
i = i + 1: y = y + 1: x = x + 1
Loop
wsDest.Range("J" & y) = "Total": wsDest.Cells(y, "M").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)"
wsDest.Cells(y, "O").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)": wsDest.Cells(y, "P").FormulaR1C1 = "=SUM(R[-10]C:R[-1]C)"
wsDest.Range("J" & y & ":P" & y).Interior.Color = 65535
i = 1
y = y + 2
cRng.Rows(1).Copy wsDest.Cells(y, 1)
y = y + 2
cRng.Rows(2).Copy wsDest.Cells(y, 1)
Application.CutCopyMode = False
y = y + 1
Loop
Application.ScreenUpdating = True
End Sub
[/CODE]

Thank you, you excelled. I wish you a happy holiday 🤝🤝🤝
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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