Asa, Thank you very much for taking sometime and explaining the concept for us. Skanda. On Fri, Feb 24, 2012 at 3:00 AM, Asa Rossoff <a...@lovetour.info> wrote:
> Hi Skanda,**** > > I don't know much about SAS, but here is an example of a common use of --* > *** > > =SUMPRODUCT(--(Customer[City]="Paris"),--(Customer[Country]<>"France"))*** > * > > The above uses an Excel 2010 Table notation. You can replace > "Customer[City]" and "Customer[Country]" with the data range in columns > containing the City and Country in a list of Customers.**** > > ** ** > > The formula actually counts the number of records that meet both criteria, > because each criterion is evaluated to 0 or 1 and then multiplied by the > other for each record, resulting in a 0 unless both criteria are met, when > it will be 1. Then the results for all the records are added together.*** > * > > ** ** > > If you want to know, say, the total sales for that set of customers:**** > > > =SUMPRODUCT(--(Customer[City]="Paris"),--(Customer[Country]<>"France"),Customer[Sales]) > **** > > will work because the 0 or 1 for each record will then be multiplied by > the Sales amount before being added to other record's results.**** > > ** ** > > ** ** > > In Excel 2007+ the basic examples I just gave could be achieved more > efficiently (quicker calculation) using COUNTIFS and SUMIFS, which wouldn't > require the double negative.**** > > ** ** > > I'll also throw in to my explanations that sometimes it's useful to not > convert all booleans to numbers, and take advantage of the fact that > booleans are ignored by aggregate functions.**** > > ** ** > > Take the MEDIAN and AVERAGE functions, for example. Including 0 values > for records not of interest will skew the results. Instead, you can handle > the boolean values using IF(boolean,value to aggregate) (you can omit the > value-if-false part because IF will just return a boolean False when it's > omited, which will then be disregarded by the aggregate function as if > there was no value at all):**** > > > =MEDIAN(IF((Customer[City]="Paris")*(Customer[Country]<>"France")*NOT(ISBLANK(Customer[Sales])),Customer[Sales])) > **** > > ** ** > > The attached files demonstrate. The xlsx version has both 2010 table > reference and traditional range reference versions of the formulas; the xls > version just has range versions.**** > > ** ** > > Asa**** > > ** ** > > ** ** > > *From:* excel-macros@googlegroups.com [mailto: > excel-macros@googlegroups.com] *On Behalf Of *Skanda > *Sent:* Thursday, February 23, 2012 9:10 AM > > *To:* excel-macros@googlegroups.com > *Subject:* Re: $$Excel-Macros$$ Meaning of minus minus or -- in an Excel > function**** > > ** ** > > I'm from SAS background. Can anybody please provide an example for the > following scenario.**** > > **** > > On Thu, Feb 23, 2012 at 11:02 AM, Sam Mathai Chacko <samde...@gmail.com> > wrote:**** > > I know I mentioned otherwise in > http://osdir.com/ml/excel-macros/2011-12/msg00084.html > > However,* you cannot use ++* > > You can use +0, *1, -0, /1, ^1 etc, but -- is the most elegant and common > approach. > > Regards, > > Sam Mathai Chacko **** > > ** ** > > On Thu, Feb 23, 2012 at 12:21 PM, Asa Rossoff <a...@lovetour.info> wrote:** > ** > > Hi Johann,**** > > To add to Noorain's explanation:**** > > **** > > Boolean (True/False) values cannot be added, multiplied, averaged, etc. by > aggregate functions such as SUM(), PRODUCT(), AVERAGE(), MEDIAN(), and > SUMPRODUCT. In fact, boolean values are always completely ignored by > aggregate functions.**** > > **** > > To summarize boolean values with an aggregate function, you must convert > the the boolean to a number. When you use a value in a formula as if it > were a different type of data, Excel will in most circumstances convert the > value to that type of data. This implicit method of data type conversion > is called coercion. You can coerce boolean values to a number, text > representations of a number to a number, textual dates/times to actual > date/times (dateserials), anything to text,…**** > > **** > > Boolean values can be coerced to a number (1 for True, 0 for False) in > several ways. If you use an arithmetic operator with a boolean value, the > boolean is coerced to become a number. In recent versions of Excel, the > N() function performs an explicit conversion to a number and works in many > circumstances (although arithmetic coercion works more broadly). For > completeness there is also the similar VALUE function which can convert > most data types to numbers, but not booleans.**** > > **** > > When you don't need to use an arithmetic operator in your formula already, > but you need to coerce a boolean value, you have to device a neutral > expression that includes an arithmetic operator, like --boolean, boolean*1, > boolean+0, boolean/1. -- is often favored. Your formula is still clean, > the -- form would probably not be used in other circumstances, and it's a > fast calculation for Excel.**** > > **** > > Usually the requirement to utilize boolean values as numbers comes up in > array formulas and SUMPRODUCT formulas (similar because SUMPRODUCT resolves > array formulas too). Numeric representations of boolean values is useful > in these formulas because when multiplied by another value, that value can > either be included in a summary when the boolean is True/1, or not, when > False/0. That boolean value or expression has become a criteria for what > to summarize.**** > > **** > > Asa**** > > **** > > *From:* excel-macros@googlegroups.com [mailto: > excel-macros@googlegroups.com] *On Behalf Of *NOORAIN ANSARI > *Sent:* Wednesday, February 22, 2012 7:06 PM > *To:* excel-macros@googlegroups.com > *Subject:* Re: $$Excel-Macros$$ Meaning of minus minus or -- in an Excel > function**** > > **** > > Dear johann,**** > > **** > > The -- is used as an unary operator to convert a boolean value ie, > TRUE/FALSE in to 1/0. Sumproduct for example does not evaluate non-numeric > values that results in a formula like the boolean results in the array > equation A1:A10="johann".**** > > So to negate this, we use unary operator -- with TRUE or FALSE to give 1 > or 0**** > > We can also use ++ ,+0,*1**** > > In fact you can also use a multiplier or a divisor of 1**** > > In case you'd like more information, look up in google. Here's something > from an Excel MVP**** > > http://www.mcgimpsey.com/excel/formulae/doubleneg.html**** > > On Thu, Feb 23, 2012 at 5:24 AM, johann <josle...@gmail.com> wrote:**** > > Hi Cyberspace, > > I'd like to understand the meaning of "--" in front of an Excel > function like : > =--sumproduct(...) > =--substitute(...) > ... and other I can't recall > > I know that in some programming language it's a way to "decrement" a > variable like i = i - 1 can be i-- or --i following the precedence of > the operator --. > > Thanks, > Cyberuser > > -- > 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**** > > > > > -- **** > > Thanks & regards,**** > > Noorain Ansari**** > > *http://noorainansari.com/***** > > *http://excelmacroworld.blogspot.com/*<http://excelmacroworld.blogspot.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**** > > > > **** > > -- > Sam Mathai Chacko **** > > ** ** > > -- > 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