VBA Copy and Paste Cell Value Only - Not Formula

wguidry

New Member
Joined
Apr 22, 2003
Messages
42
I am having problems with the code listed below. The syntax is fine, but it returns a value of #N/A. The code copies a value from a second sheet and pastes it into the current sheet.

The cell being copied derives its value from a VLOOKUP function on a different sheet. I think this may be creating the problem.

Is there a way to copy a cell's numeric value only and not the formula? Or maybe paste the value only (like the Paste Special - Values Only menu item)?
---------------------------------------------
With Worksheets("Daily Calcs")
For i = 2 To 360
If Worksheets("Positions").Cells(i, 20).Value = "RED LINE" Then
Set rng6 = .Range("A3").End(xlDown).Offset(0, 41)
rng6.Copy
ActiveSheet.Paste Destination:=Worksheets("Positions").Range("W2")
End If
Next i
End With

Thanks,
Will
 

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.
to copy a formula result as a value instead of the formula, instead of '.Paste', use '.PasteSpecial'

just replace your line of code:
ActiveSheet.Paste Destination:=Worksheets("Positions").Range("W2")

with this line:
Worksheets("Positions").Range("W2").PasteSpecial xlPasteValues

see the excel vba help file for the use of the PasteSpecial method. it's pretty straightforward.

hth
kevin
 
Upvote 0
if i could make one more suggestion, instead of using:

Set rng6 = .Range("A3").End(xlDown).Offset(0, 41)
rng6.Copy
ActiveSheet.Paste Destination:=Worksheets("Positions").Range("W2")

you could use:

Worksheets("Positions").Range("W2").value = .Range("A3").End(xlDown).Offset(0, 41).value

which will accomplish the same thing - plus it will allow your code to run more quickly by avoiding the use of copy and paste

kevin
 
Upvote 0
It worked! (Why would I doubt the mighty Kevin?) And thanks for this tip on speeding up the code.
 
Upvote 0
I'm trying to copy a cell from one worksheet to the other in the same column, but I want to copy the values. I've tried reviewing both this and the PasteSpecial, but I'm doing something incorrect with the destination...please help.
<CODE>
FoundCell.Cells.EntireColumn.Copy ActiveWorkbook.Sheets(2).Columns(FoundCell.Column) 'this works

FoundCell.EntireColumn.PasteSpecial xlPasteValues ActiveWorkbook.Sheets(2).Columns(FoundCell.Column) 'this fails

</CODE>
 
Upvote 0
Will, I suggest you start a new thread and provide more info as to your layout. Also, post the code leading up to the FoundCell. It is also highly likely you don't need to copy the ENTIRECOLUMN.

lenze
 
Upvote 0
I am using following coding to insert from one sheet to another but i want to have only cell values not the formula of cell. can you please suggest
Sheets("INS").Select
Rows("1:13").Select
Selection.Copy
Sheets("VW250").Select
ActiveCell.Select
Selection.Insert Shift = xlDown
Application.CutCopyMode = False
 
Upvote 0
Dim lr As Long, i As Long
With Sheets("DAILY LOG")
lr = .Range("G" & Rows.Count).End(xlUp).Row
For i = 19 To lr
With .Range("G" & i)
If .Value = "OS" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("A" & Rows.Count).End(xlUp).Offset(1)
If .Value = "OD" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("B" & Rows.Count).End(xlUp).Offset(1)
If .Value = "NSP" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("C" & Rows.Count).End(xlUp).Offset(1)
If .Value = "SL" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("D" & Rows.Count).End(xlUp).Offset(1)
If .Value = "ULO" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("E" & Rows.Count).End(xlUp).Offset(1)
If .Value = "ULF" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("F" & Rows.Count).End(xlUp).Offset(1)
If .Value = "OT" Then .Offset(, -2).Resize(, 1).Copy Destination:=Sheets("Delay Duration").Range("G" & Rows.Count).End(xlUp).Offset(1)
End With
Next i
End With

This code copies and pastes the formulas whereas I only want the values to be pasted.

Is it possible to do this by altering the Destination slightly?

Thanks
 
Upvote 0
I'm no Pro, but If your Offset and Resize Values are the only values your routine will encounter, I would consolidate those into one, and then copy and .pastespecial .xlValue
ws1.Cells(I, 6).Copy
ws.Cells(9, 4).PasteSpecial xlPasteValues
 
Upvote 0

Forum statistics

Threads
1,213,515
Messages
6,114,080
Members
448,548
Latest member
harryls

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