How do I change this MVB macro to only paste the data (not the formulas) to a new sheet?

cram8603

New Member
Joined
Nov 3, 2008
Messages
3
This is a macro I found and I have modiffied it to fit my purpose with the exception that I don't know how to make it "paste special". I don't want to copy the formulas, i just want to copy the data.

Code:
Sub HistoricalData()
Dim TargetSht As Worksheet, SourceSht As Worksheet, SourceCol As Integer, SourceCells As Range

'If an error occurs skip code to the Err-Hanlder line and the display the error message.
On Error GoTo Err_Handler

'This is the sheet where your copy information from. Change "Sheet1" to the name of your soure sheet
Set SourceSht = ThisWorkbook.Sheets("Sheet1")

'Name of the sheet where data is to be copied to. Rename Sheet2 to the name of your target sheet
Set TargetSht = ThisWorkbook.Sheets("Sheet2")

'This is the cells you will copy data from. This is targeting cells B1 to the last used cell in column B
Set SourceCells = SourceSht.Range("B1:B" & SourceSht.Range("B65536").End(xlUp).Row)

'This is finding the next column available in the target sheet. It assumes dates will be in row 1 and data in row 2 down
If TargetSht.Range("A1").Value = "" Then
    'Cell A1 is blank so the column to put data in will be column #1 (ie A)
    SourceCol = 1
ElseIf TargetSht.Range("IV1").Value <> "" Then
    'Cell IV1 has something in it so we have reached the maximum number of columns we can use in this sheet.
    'Dont paste the data but advise the user.
    MsgBox "There are no more columns available in the sheet " & TargetSht.Name, vbCritical, "No More Data Can Be Copied"
    'stop the macro at this point
    Exit Sub
Else
    'cell A1 does have data and we havent reached the last column yet so find the next available column
    SourceCol = TargetSht.Range("IV1").End(xlToLeft).Column + 1
End If

'Put in the date in the appropriate column in row 1 of the target sheet
TargetSht.Cells(1, SourceCol).Value = Format(Date, "DD/MM/YYYY")

'We can now start copying data. This will copy the cells in column B from the source sheet to row 2+ in the target sheet
SourceCells.Copy TargetSht.Cells(2, SourceCol)

'Advise the user that the process was successful
MsgBox "Data copied successfully!", vbInformation, "Process Complete"

Exit Sub 'This is to stop the procedure so we dont display the error message every time.
Err_Handler:
MsgBox "The following error occured:" & vbLf & "Error #: " & Err.Number & vbLf & "Description: " & Err.Description, _
        vbCritical, "An Error Has Occured", Err.HelpFile, Err.HelpContext

End Sub
 
Last edited by a moderator:

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
Welcome to the board...

It looks like it's this line that is copying and pasting..

SourceCells.Copy TargetSht.Cells(2, SourceCol)

Try changing it to

SourceCells.Copy
TargetSht.Cells(2, SourceCol).PasteSpecial xlPasteValues

Hope that helps
 
Upvote 0

Forum statistics

Threads
1,217,490
Messages
6,136,942
Members
450,034
Latest member
amcaddress

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