Code to copy only values from a cell with formula to another cell

girapas

Board Regular
Joined
Apr 20, 2004
Messages
150
I have a sheet in which cells at columns A to F change through a formula.
What is the code for the "Copy - Paste Special - Values (only, but not the formula)" when any value of cells A to F change?
Thanks in advance...
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
If you had a formula in A1 that you want the value (not the formula) for in B1, you could just do this:
Code:
[B1].Value = [A1].Value

No need to copy or paste, just making the values equal.

Hope it helps.
 
Upvote 0
Thank you for the reply. It works fine for a single cell, but I can't manage it with multiple cells in a column. I get the compile error "Invalid qualifier" for [cell2]
I've put the code:

Private Sub Worksheet_Change(ByVal Target As Range)
Dim i As Byte
Dim cell1, cell2 As String

For i = 1 To 100
cell1 = "A" & i
cell2 = "B" & i
If Target.Address = cell1 Then [cell2].Value = [cell1].Value
Next i

End Sub
 
Upvote 0
Hi,
It looks to me like your code (if it worked as written) would simply be testing to see if the change happened within the range A1:A100, and if so, make the cell in column B equal to the cell that got changed in column A. (yes?)

If that's correct then you don't need to assign variables and loop through the range, we can do it with just this one liner:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("A1:A100")) Is Nothing Then _
   Target(, 2).Value = Target.Value
End Sub

If this is not your intent then can you post back with what is?
Oh, and one question, are the values in column A getting changed manually, or are they formulas that are updating?
 
Upvote 0
Yes, it's correct. I want to do what you've written, but the code you gave me doesn't work.
Notice that each cell in column A changes by a formula. For that reason I asked for the Copy - Paste Special - Values (only) code.
 
Upvote 0
I suspected that might be the case.
We should then use the worksheet calculation event instead of the change event.
If you were to (for some reason) want to loop through A1:A100, you could do it like this:
Code:
Private Sub Worksheet_Calculate()
Dim i As Long
For i = 1 To 100
  Cells(i, "B").Value = Cells(i, "A").Value
Next i
End Sub
But... since this is not determining which formula return has changed with the update, we can simply copy A1:A100 & paste as values to B1:B100. (like so):
Code:
Private Sub Worksheet_Calculate()
Range("A1:A100").Copy
Range("B1:B100").PasteSpecial Paste:=xlValues, Operation:=xlNone, SkipBlanks:=False, Transpose:=False
End Sub
Does either one of these work for what you want?
 
Upvote 0
You're very welcome.

(And actually, they both work great but the second one will be [marginally] faster.) ;)
 
Upvote 0

Forum statistics

Threads
1,214,516
Messages
6,119,980
Members
448,934
Latest member
audette89

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