Hi H., True, Value2 is not necessary for the Format function version, but depending on which alternative you are comparing it to, it is faster, more predictable, or both.
with the options: CELL CELL.Value CELL.Value2 CELL.Text . * CELL is a Range object, so if you use it in the context of a value, you are implicitly asking for the default property of the range, which is for most practical purposes the same as the Value property. Always best to be explicit, though (especially because there are times when the Range might be used when you want the Value and vice-versa) * CELL.Value is the value of the cell, converted to a similar VBA datatype based on the contents of the cell and the way the cell is formatted. The problems with this are: 1) this takes time, and you often don't need this to occur, 2) the VBA datatypes do not hold exactly the same information, so there is a loss of data. For example, the VBA Date datatype is lower resolution for times (while supporting a wider range of dates) than date/times on the worksheet. The VBA Currency data type is not a floating point number, but a scaled decimal, which is it's strength (no rounding errors) -- but currencies on the worksheet are floating point numbers. VBA Currency stores 4 digits afte the decimal place; floating point numbers on the worksheet store slightly over 15 significant digits (either side of the decimal). * CELL.Value2 provides the exact underlying value of cells. It's the only way to preserve those values in VBA, and it's faster than CELL.Value. Value2 is always my first choice. I fall back to Value when I require the datatype conversion that Value does. * CELL.Text is a texual representation of the cell's data as formatted on the worksheet. This often results in a loss of underlying data. Unless you need a formatted string, it requires conversion back to an appropriate datatype (whether you do it explicitly or allow VBA to do it implicitly), and CELL.Text returns "" for hidden columns. Asa From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com] On Behalf Of tangledweb Sent: Thursday, June 28, 2012 10:25 PM To: excel-macros@googlegroups.com Subject: Re: $$Excel-Macros$$ Re: Can I get the day of the week (e.g. Friday) from the date already encoded in a string? Thanks Asa and belatedly Noorain. The format function worked and as it happens the other method was returning the wrong day for all those who might use it. The .value2 does not seem to be necessary but I left it anyway. On Wednesday, June 27, 2012 10:09:16 PM UTC-7, tangledweb wrote: Asa! Good to hear from you. I am fine. Hope the same for you. The example I posted seemed to work but I admit I did not check to see if the correct day was returned. Tomorrow I will do that and try out your format function version (which I think someone else posted earlier but I had not tried it yet). On Wed, Jun 27, 2012 at 9:35 PM, Asa Rossoff <a...@lovetour.info> wrote: > Hi! Hope you are well. > > > > The "VBA way" is to use VBA's Format function (Replace CELL with the range > object for the cell desired): > > Format(CELL.Value2, "dddd") > > > > If you wanted to use the TEXT function, the example given -- I believe -- > will return incorrect results. These versions would return the correct > result (replace WORKSHEET/CELL): > > Worksheetfunction.Text(CELL, "dddd") > > WORKSHEET.evaluate("text(" & CELL.address & ",""dddd"")") > > WORKSHEET.evaluate("text(" & CELL.value2 & ",""dddd"")") > > WORKSHEET.evaluate("text(""" & CELL.value & """,""dddd"")") > > > > The Format function would be my preference, but of the TEXT function > versions, the first is most efficient, then second, then third. The first > uses a cell reference to supply the date value, the second a dateserial > (Value2 returns a number for dates), the third a text representation of the > date (the Value property converts date/time values on the worksheet to VBA's > Date datatype, but when you concatenate it with a string, VBA's datatype > coercion behavior is to convert it to a text representation using the system > locale's short date and/or short time settings). > > > > The previous example acquired the cell value via it's Text property, which > is dangerous and rarely desired. Text returns the value of the cell as > formatted, but if the column is hidden, it returns an empty string. Also, > the Day function will cause trouble. It's a common misunderstanding to > think it should be used with the Text function, but this is almost never > desired. Day returns a number between 1 and 7 to indicate the day of the > week. Text formats dates or dateserial numbers, not day numbers. Text will > interpret numbers between 1 and 7 as the first 7 days on it's dateserial > calendar, which are 1/1/1900 through 1/7/1900. > > > > Asa > > > > > > From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com] > On Behalf Of tangledweb > Sent: Wednesday, June 27, 2012 8:23 PM > > > To: excel-macros@googlegroups.com > Subject: $$Excel-Macros$$ Re: Can I get the day of the week (e.g. Friday) > from the date already encoded in a string? > > > > The custom format will not work as I need the data to have the date except > for one special test. > > > > This worked so thanks Lalit. > > > > Evaluate("=Text(Day(""" & Sheets(RawData).Cells(count, BarDate).Text & """), > ""dddd"")") > > > > Oddly when I used "Sheet1" instead of RawData which is the same sheet I got > a subscript out of range but worked fine with the alias. > > > > > On Tuesday, June 26, 2012 8:47:02 PM UTC-7, tangledweb wrote: > > If I already have Sheets(RawData).Cells(count, BarDate).Text having a value > like 6/26/2012 is there a way to get the day of the week as a number or > string for that date that does not require splitting it into its parts and > feeding them to some function? If the latter the .net examples I found for > that did not make sense to me so how is it done? > > -- > 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 > > To unsubscribe, send a blank email to > excel-macros+unsubscr...@googlegroups.com <mailto:excel-macros%2bunsubscr...@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 > > To unsubscribe, send a blank email to > excel-macros+unsubscr...@googlegroups.com <mailto:excel-macros%2bunsubscr...@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 To unsubscribe, send a blank email to excel-macros+unsubscr...@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 To unsubscribe, send a blank email to excel-macros+unsubscr...@googlegroups.com