To retrieve a multi-column array I resorted to "transpose(transpose(round(a1:b10,2)))" form.
From: Asa Rossoff [mailto:a...@lovetour.info] Sent: Wednesday, April 11, 2012 5:18 PM To: 'excel-macros@googlegroups.com' Subject: RE: $$Excel-Macros$$ Argh. Previously posted evaluate function replacing loop has unnoticed major error 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