Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.programming
|
|||
|
|||
![]()
Range("e" & i).Value = WorksheetFunction.SumIfs(balrange, acctrange, "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & Array(2075554, 2075664, 2075665, 2075666, 2075667, 2075668, 2075669, 2075670, 2075671, 2075672, 2075673), dpdrange, "=" & goal1)
trying to use the Array for multiple conditions is not working as is. of course {}'s are invalid charachters in VBA, so that doesnt work.. and every other search i've done for a solution has not been related to the worksheetfunction portion of the code. help please! thank you in advance! |
#2
![]()
Posted to microsoft.public.excel.programming
|
|||
|
|||
![]()
"Matthew Dyer" wrote:
Range("e" & i).Value = WorksheetFunction.SumIfs(balrange, acctrange, "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & Array(2075554, 2075664, 2075665, 2075666, 2075667, 2075668, 2075669, 2075670, 2075671, 2075672, 2075673), dpdrange, "=" & goal1) trying to use the Array for multiple conditions is not working as is. of course {}'s are invalid charachters in VBA, so that doesnt work. It wouldn't work in Excel either. In Excel, we would have to use a formula of the form: SUMPRODUCT(SumIfs(balrange, acctrange, "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & {2075554, 2075664, 2075665, 2075666, 2075667, 2075668, 2075669, 2075670, 2075671, 2075672, 2075673}, dpdrange, "=" & goal1)) So we might want to write (conceptual only; does not work!): Dim v As Variant v = Array(2075554, 2075664, 2075665, 2075666, 2075667, 2075668, 2075669, _ 2075670, 2075671, 2075672, 2075673) Range("e" & i).Value = WorksheetFunction.SumProduct( _ WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & v, _ dpdrange, "=" & goal1) That does not work because WorksheetFunction.SumIfs is evaluated only once. So I think we must write the following in VBA (untested): Dim cnt As Long, v As Variant cnt = 0 For Each v In Array(2075554, 2075664, 2075665, 2075666, 2075667, _ 2075668, 2075669, 2075670, 2075671, 2075672, 2075673) cnt = cnt + WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & v, _ dpdrange, "=" & goal1) Next Range("e" & i).Value2 = cnt FYI, note that I use Value2 instead of Value. It has been noted that sometimes unintended results arise from using Value. In particular, if the cell is formatted as Currency, Accounting or a similar Custom format, the value stored is rounded to 4 decimal places, consistent with VBA type Currency. |
#3
![]()
Posted to microsoft.public.excel.programming
|
|||
|
|||
![]()
Minor improvement....
"joeu2004" wrote: cnt = cnt + WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & v, _ dpdrange, "=" & goal1) Simply: cnt = cnt + WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, v, _ dpdrange, "=" & goal1) No need for "="&v. "=" is implicit. |
#4
![]() |
|||
|
|||
![]()
bài viết hay đó, chúc thớt ngủ ngon nha
|
#5
![]()
Posted to microsoft.public.excel.programming
|
|||
|
|||
![]()
On Thursday, February 26, 2015 at 9:42:27 AM UTC-7, joeu2004 wrote: Minor improvement.... "joeu2004" wrote: cnt = cnt + WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, "=" & v, _ dpdrange, "=" & goal1) Simply: cnt = cnt + WorksheetFunction.SumIfs(balrange, acctrange, _ "=" & rangemin, acctrange, "<=" & rangemax, listrange, v, _ dpdrange, "=" & goal1) No need for "="&v. "=" is implicit.
the nested loop for all v's in my array works perfectly. thank you guys for your help! |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Nested if/then or array??? | Excel Worksheet Functions | |||
nested MATCH within Array formula? | Excel Worksheet Functions | |||
nested array formula's | Excel Worksheet Functions | |||
Nested array functions? | Excel Worksheet Functions | |||
Nested if in Array | Excel Worksheet Functions |