tmprange.Value2 = .Evaluate("transpose(transpose(round(" & tmprange.Address
& ",2)))")

should work for a multi-column range.

The performance of Value2 depends on whether you're retrieving or assigning
values to/from the worksheet, and what type of data and formats are applied
on the worksheet.  In some cases they might perform the same depending on
those factors, but if you make Value2 your go-to, you will always get the
same or better performance, and never have to worry about values being
changed when moved between the worksheet and VBA.

Asa

-----Original Message-----
From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
On Behalf Of Domain Admin
Sent: Wednesday, April 11, 2012 5:39 PM
To: excel-macros@googlegroups.com
Subject: Re: $$Excel-Macros$$ Argh. Previously posted evaluate function
replacing loop has unnoticed major error

I thought is might be that ROUND could only work on one value.
Blaming yourself when I did not notice that my entire range was being
clobbered is magnanimous of you.

One thing you said is incorrect.  The range is not just one column (is
that the problem).
It is 5 columns.  I read the help on index (odd one parameter is
double but others variant).
It seems like it is saying you can get back an entire row, or an
entire column, or the intersection,
but not the entire 2 dimensional range.  So would I do 5 evaluates
(one for each column) or
is there a better way to use index?
By the way I timed value2 vs value and got zero difference but only
20k cells may not be enough
to see a difference.

Since the array method was only slightly slower than this perhaps I
should use that and use the
array for the rest of my processing too which I was already considering.

On Wed, Apr 11, 2012 at 5:17 PM, Asa Rossoff <a...@lovetour.info> wrote:
> Hi Howard,
>
> Seems like an Excel bug.. Sorry for not testing the suggestion.  Evaluate
> may not be fully documented for a reason.  However, it is a great useful
> function, just if you aren't getting the result you expect, you may have
to
> look for a workaround.  I just posted a query in a developers forum with
> aomse big hitters to see if I can get an explanation for what you're
seeing,
> but in the meantime, here is a workaround.
>
>
>
> 1.       What you've seen with your use of Evaluate is evaluate returning
> only a single value -- the first value in the array, rather than the whole
> array as Evaluate usually does.
>
> 2.       The INDEX function can be use to extract a reference to any
> position in an array, or a whole row or column from an array.
>
> 3.       Here is a modification of your statement that works in my test by
> using index to specify to return the first column from the array (which of
> course is the whole array in this case):
>
> tmprange.Value2 = .Evaluate("index(round(" & tmprange.Address & ",2),,1)")
>
>
>
> I used Value2 since it's usually faster, but you can use Value if you
> prefer.  INDEX is the relevant change.
>
>
>
> Asa
>
>
>
> From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
> On Behalf Of tangledweb
> Sent: Wednesday, April 11, 2012 2:28 PM
> To: excel-macros@googlegroups.com
> Subject: $$Excel-Macros$$ Argh. Previously posted evaluate function
> replacing loop has unnoticed major error
>
>
>
> I used the evaluate function below to replace the commented out loop
portion
> for better performance in rounding off all the cells in a range.
>
> It was certainly fast and it performed the round function correctly but it
> also replaced every single cell in the range with the value of the first
>
> cell (ok you can laugh now).  Any idea what is wrong with it?  Kind of
hard
> to debug a single line of code.
>
>
>
>     With Sheets(RawData)
>         Set tmprange = .Range(.Cells(2, 3), .Cells(stoprawdata, 7))
>         tmprange.Value = .Evaluate("round(" & tmprange.Address & ",2)")
'use
> evaluate instead of code below
> '        For Each onecell In tmprange
> '            onecell.Value = WorksheetFunction.Round(onecell, 2)
> '        Next onecell
>     End With
>
> --
> FORUM RULES (986+ members already BANNED for violation)
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
will
> not get quick attention or may not be answered.
>
> 2) Don't post a question in the thread of another member.
>
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
>
> 4) Acknowledge the responses you receive, good or bad.
>
> 5) Cross-promotion of, or links to, forums competitive to this forum in
> signatures are prohibited.
>
> NOTE : Don't ever post personal or confidential data in a workbook. Forum
> owners and members are not responsible for any loss.
>
>
----------------------------------------------------------------------------
--------------------------
> To post to this group, send email to excel-macros@googlegroups.com
>
> --
> FORUM RULES (986+ members already BANNED for violation)
>
> 1) Use concise, accurate thread titles. Poor thread titles, like Please
> Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice
will
> not get quick attention or may not be answered.
>
> 2) Don't post a question in the thread of another member.
>
> 3) Don't post questions regarding breaking or bypassing any security
> measure.
>
> 4) Acknowledge the responses you receive, good or bad.
>
> 5) Cross-promotion of, or links to, forums competitive to this forum in
> signatures are prohibited.
>
> NOTE : Don't ever post personal or confidential data in a workbook. Forum
> owners and members are not responsible for any loss.
>
>
----------------------------------------------------------------------------
--------------------------
> To post to this group, send email to excel-macros@googlegroups.com

-- 
FORUM RULES (986+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please
Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will
not get quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security
measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in
signatures are prohibited. 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum
owners and members are not responsible for any loss.

----------------------------------------------------------------------------
--------------------------
To post to this group, send email to excel-macros@googlegroups.com

-- 
FORUM RULES (986+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in 
signatures are prohibited. 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum 
owners and members are not responsible for any loss.

------------------------------------------------------------------------------------------------------
To post to this group, send email to excel-macros@googlegroups.com

Reply via email to