Macro Working Only Intermittently

rob51852

Board Regular
Joined
Jun 27, 2016
Messages
171
Office Version
  1. 2016
Platform
  1. Windows
Hi,

I have put together the macro below to do various things (sort, add formulae, copy and reformat).

For some reason the code to insert formulae only works intermittently and I can't pinpoint the cause. Can anyone see what the issue might be?

Thanks


VBA Code:
Sub CopyToStore()

'Sort columns

With ThisWorkbook.Sheets("Data").Sort
     .SortFields.Add Key:=Range("A1"), Order:=xlAscending
     .SortFields.Add Key:=Range("F1"), Order:=xlAscending
     .SortFields.Add Key:=Range("B1"), Order:=xlAscending
     .SetRange Range("A1:U100000")
     .Header = xlYes
     .Apply
End With

'Insert formulae

FinalRow = ThisWorkbook.Sheets("Data").Cells(Rows.Count, 2).End(xlUp).Row 'Counts # of rows in the data set

Range(ThisWorkbook.Sheets("Data").Cells(3, 22).Address, Cells(FinalRow, 22).Address).Formula = "=J3-J2"

'Copy to Store

With ThisWorkbook.Worksheets("Data")
 .Range("A2:V" & .Cells(Rows.Count, "A").End(xlUp).Row).Copy
 ThisWorkbook.Worksheets("Store").Range("A" & .Rows.Count).End(xlUp).Offset(1).PasteSpecial Paste:=xlPasteValues
End With

'Format time value

With ThisWorkbook.Worksheets("Store")
 .Range("B:B").NumberFormat = "dd/mm/yyyy hh:mm:ss.000"
End With

End Sub
 

Some videos you may like

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
55,526
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Sub CopyToStore()

'Sort columns

With ThisWorkbook.Sheets("Data").Sort
     .SortFields.Add key:=Range("A1"), Order:=xlAscending
     .SortFields.Add key:=Range("F1"), Order:=xlAscending
     .SortFields.Add key:=Range("B1"), Order:=xlAscending
     .SetRange Range("A1:U100000")
     .Header = xlYes
     .Apply
End With

'Insert formulae
With ThisWorkbook.Sheets("Data")
   FinalRow = .Cells(Rows.Count, 2).End(xlUp).Row 'Counts # of rows in the data set

   .Range(.Cells(3, 22), .Cells(FinalRow, 22)).Formula = "=J3-J2"

'Copy to Store

   .Range("A2:V" & .Cells(Rows.Count, "A").End(xlUp).Row).Copy
   ThisWorkbook.Worksheets("Store").Range("A" & .Rows.Count).End(xlUp).Offset(1).PasteSpecial Paste:=xlPasteValues
End With

'Format time value

With ThisWorkbook.Worksheets("Store")
 .Range("B:B").NumberFormat = "dd/mm/yyyy hh:mm:ss.000"
End With

End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,127,529
Messages
5,625,355
Members
416,096
Latest member
forevans

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
Top