Range1 = Range2 not quite working... with numeric values as strings/text

cboshdave

Board Regular
Joined
Jan 12, 2011
Messages
68
In spreadsheet 1 I have a list of codes ('00001, '00045, 'J1364 etc - not all are numeric). They are displaying fine as Text in xls 1.
I need to essentially copy them to xls 2. I run the following code:
Code:
oWB1.Sheets(1).Range(Cells(r1, cPaste).Address, Cells(r1 + rHeight, cPaste).Address).Value = oWB2.Sheets(1).Range(Cells(rStart, 1).Address, Cells(rStart + rHeight, 1).Address).Value

It works and basically "copies" the range. But reformats my values to (1, 45, 'J1364). My target column is defined as Text. Doesn't seem to matter. I have also tried to wrap the equation to the right of the "=" in a Format( value, "00000"). I also tried string( "0", value). I just get mismatches on that. I actually do make it work by formatting the target column as "Text". My only concern with that is that it is subject to change my users. Maybe this is as good as it gets?

I wish Excel would not mess with some text values! Thoughts?

Thanks,
Dave
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
You can adapt this example to work with your worksheets and ranges. Here A1:A3 holds '00001, '00045, J1364. D1:D3 maintains the text format for the cells that Excel is eager to convert to numbers.
Code:
 Sub MaintainTextFormat()
Dim V As Variant, i As Long
'change worksheets, ranges to suit
V = Range("A1:A3").Value
For i = 1 To UBound(V, 1)
    If IsNumeric(V(i, 1)) Then V(i, 1) = "'" & CStr(V(i, 1))
Next i
Range("D1:D3").Value = V
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,901
Messages
6,175,277
Members
452,629
Latest member
SahilPolekar

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