Help with code to see if it will

cfer

Well-known Member
Joined
Jul 29, 2002
Messages
560
Hi All,

I have the following code, it works fine, but can take about 9 seconds to run.

Is there anything I can change or add to make it execute a little faster.

Sub UpdateLogWorksheet()

Application.ScreenUpdating = False
Application.EnableEvents = False
Dim historyWks As Worksheet
Dim inputWks As Worksheet
Dim NextRow As Long
Dim oCol As Long

Dim myRng As Range
Dim myCopy As String
Dim myCell As Range

' Application.ScreenUpdating = False
'cells to copy from Input sheet - some contain formulas
myCopy = "E7,E9,E11,E13,E15,E17,E19,E21,E23,E25,E27,E29,E31,E33,E35,E37,E39,E42,E44,F48,K7,K9,K11,K13,K15,K17,K19,K21,K23,K25,K27,K29,K31,K33,K39,K42,K44,N48,P35,S9,S11,S13,S15,S17,S19,S21,S23,S25,S27,S31,S48,V9,V11,V13,V15,V17,V19,V21,V23,V25,V27"

Set inputWks = Worksheets("Input")
Set historyWks = Worksheets("Data")
'Application.ScreenUpdating = False
With historyWks
NextRow = .Cells(.Rows.count, "A").End(xlUp).Offset(1, 0).Row
End With

With inputWks
Set myRng = .Range(myCopy)

'If Application.CountA(myRng) <> myRng.Cells.Count Then
' MsgBox "Please fill in all the cells!"
'Exit Sub
' End If
End With
' Calculate
With historyWks
With .Cells(NextRow, "A")
.Value = Now
.NumberFormat = "dd/mm/yyyy hh:mm:ss"
End With
.Cells(NextRow, "B").Value = Application.UserName

oCol = 8
For Each myCell In myRng.Cells
historyWks.Cells(NextRow, oCol).Value = myCell.Value
oCol = oCol + 1
Next myCell
End With
Worksheets("Data").Select
' Worksheets("Data").Range("C2").Copy Destination:=Worksheets("Data").Range("C65536").End(xlUp).Select

Range("C2").Select
Selection.Copy
'Range("C65536").End(xlUp).Select
Range("a65536").Select
Selection.End(xlUp).Offset(0, 2).Select
ActiveSheet.Paste
Range("D2").Select
Selection.Copy
Range("a65536").Select
Selection.End(xlUp).Offset(0, 3).Select
ActiveSheet.Paste
Range("E2").Select
Selection.Copy
Range("a65536").Select
Selection.End(xlUp).Offset(0, 4).Select
ActiveSheet.Paste
Range("F2").Select
Selection.Copy
Range("a65536").Select
Selection.End(xlUp).Offset(0, 5).Select
ActiveSheet.Paste
Range("G2").Select
Selection.Copy
Range("a65536").Select
Selection.End(xlUp).Offset(0, 6).Select
ActiveSheet.Paste
Range("BU2").Select
Selection.Copy
Range("a65536").Select
Selection.End(xlUp).Offset(0, 72).Select
ActiveSheet.Paste

'clear input cells that contain constants
With inputWks
On Error Resume Next
With .Range(myCopy).Cells.SpecialCells(xlCellTypeConstants)
.ClearContents
Application.GoTo .Cells(1) ', Scroll:=True
End With
On Error GoTo 0
End With


Worksheets("Input").Select
Range("D7").Select
Application.EnableEvents = True
Application.ScreenUpdating = True
End Sub

Thanks

Cfer
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
i only spent a minute on this but try this
Code:
Sub UpdateLogWorksheet()

Application.ScreenUpdating = False
Application.EnableEvents = False
Dim historyWks As Worksheet
Dim inputWks As Worksheet
Dim NextRow As Long
Dim oCol As Long
Dim i As Long, dCell As Long
Dim myRng As Range
Dim myCopy As String
Dim myCell As Range

Application.ScreenUpdating = False
Application.Calculation = xlCalculationManual
'cells to copy from Input sheet - some contain formulas
myCopy = "E7,E9,E11,E13,E15,E17,E19,E21,E23,E25,E27,E29,E31,E33,E35,E37,E39,E42,E44,F48,K7,K9,K11,K13,K15,K17,K19,K21,K23,K25,K27, K29,K31,K33,K39,K42,K44,N48,P35,S9,S11,S13,S15,S17,S19,S21,S23,S25,S27,S31,S48,V9,V11,V13,V15,V17,V19,V21,V23,V25,V27"

Set inputWks = Worksheets("Input")
Set historyWks = Worksheets("Data")
With historyWks
NextRow = .Cells(.Rows.Count, "A").End(xlUp).Offset(1, 0).Row
End With

With inputWks
Set myRng = .Range(myCopy)

'If Application.CountA(myRng) <> myRng.Cells.Count Then
' MsgBox "Please fill in all the cells!"
'Exit Sub
' End If
End With
' Calculate
With historyWks
With .Cells(NextRow, "A")
.Value = Now
.NumberFormat = "dd/mm/yyyy hh:mm:ss"
End With
.Cells(NextRow, "B").Value = Application.UserName

oCol = 8
For Each myCell In myRng.Cells
historyWks.Cells(NextRow, oCol).Value = myCell.Value
oCol = oCol + 1
Next myCell
End With
Worksheets("Data").Select
' Worksheets("Data").Range("C2").Copy Destination:=Worksheets("Data").Range("C65536").End(xlUp).Select
dCell = 2
For i = 3 To 7 Step 1
Cells(2, i).Copy Destination:=Range("A" & Rows.Count).End(xlUp).Offset(0, dCell)
dCell = dCell + 1
Next i
dCell = 0
Range("BU2").Copy Destination:=Range("A" & Rows.Count).End(xlUp).Offset(0, 72)
ActiveSheet.Paste

'clear input cells that contain constants
With inputWks
On Error Resume Next
With .Range(myCopy).Cells.SpecialCells(xlCellTypeConstants)
.ClearContents
Application.GoTo .Cells(1) ', Scroll:=True
End With
On Error GoTo 0
End With


Worksheets("Input").Select
Range("D7").Select
Application.EnableEvents = True
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
End Sub
 
Upvote 0
Hi Simon Lloyd,

Thank you very much, only takes a second now.

Excellent.

Cfer
 
Upvote 0

Forum statistics

Threads
1,224,587
Messages
6,179,735
Members
452,939
Latest member
WCrawford

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