![]() |
I think I know how to ask this sumproduct question now:
This is a sumproduct formula I have worked out to count the number of
recordable events that occurred within a date range. =SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable")) Now what I am trying to do is capture the cost of these recordable events (adding another array to sumproduct). These costs are located in cells Data!K$2:K$2550. I have not been able to get this $ total by using sumproduct. Somehow I keep screwing up. The only way I have been able to get this total is by using conditional sum- but by doing this I am not able to "pull" these calculations to adjacent cells- and I'm summarizing 20 years of data, so with each calculation only giving me a month-total, I could be entering the next 3 days if I don't figure this out. So here's the conditional-sum formula that gives the total- but that I have to enter each time: =SUM(IF(Data!$A$2:$A$2500=ListValues!A2,IF(Data!$ H$2:$H$2500=A19,IF(Data!$A$2:$A$2500<ListValues!B2 ,Data!$K$2:$K$2500,0),0),0)) Is it possible to get to this total with SumProduct? |
I think I know how to ask this sumproduct question now:
Maybe this:
=SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable"),Data!K$2:K$2550) HTH, Paul -- "Gina" wrote in message ... This is a sumproduct formula I have worked out to count the number of recordable events that occurred within a date range. =SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable")) Now what I am trying to do is capture the cost of these recordable events (adding another array to sumproduct). These costs are located in cells Data!K$2:K$2550. I have not been able to get this $ total by using sumproduct. Somehow I keep screwing up. The only way I have been able to get this total is by using conditional sum- but by doing this I am not able to "pull" these calculations to adjacent cells- and I'm summarizing 20 years of data, so with each calculation only giving me a month-total, I could be entering the next 3 days if I don't figure this out. So here's the conditional-sum formula that gives the total- but that I have to enter each time: =SUM(IF(Data!$A$2:$A$2500=ListValues!A2,IF(Data!$ H$2:$H$2500=A19,IF(Data!$A$2:$A$2500<ListValues!B2 ,Data!$K$2:$K$2500,0),0),0)) Is it possible to get to this total with SumProduct? |
I think I know how to ask this sumproduct question now:
Try this:
=SUMPRODUCT(--(Data!A$2:A$2550=ListValues!A2),--(Data!A$2:A$2550<ListValues!B2),--(Data!H$2:H$2550="Recordable"),Data!K$2:K$2550) -- Biff Microsoft Excel MVP "Gina" wrote in message ... This is a sumproduct formula I have worked out to count the number of recordable events that occurred within a date range. =SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable")) Now what I am trying to do is capture the cost of these recordable events (adding another array to sumproduct). These costs are located in cells Data!K$2:K$2550. I have not been able to get this $ total by using sumproduct. Somehow I keep screwing up. The only way I have been able to get this total is by using conditional sum- but by doing this I am not able to "pull" these calculations to adjacent cells- and I'm summarizing 20 years of data, so with each calculation only giving me a month-total, I could be entering the next 3 days if I don't figure this out. So here's the conditional-sum formula that gives the total- but that I have to enter each time: =SUM(IF(Data!$A$2:$A$2500=ListValues!A2,IF(Data!$ H$2:$H$2500=A19,IF(Data!$A$2:$A$2500<ListValues!B2 ,Data!$K$2:$K$2500,0),0),0)) Is it possible to get to this total with SumProduct? |
I think I know how to ask this sumproduct question now:
Or
=SUMPRODUCT(--(Data!A$2:A$2550=ListValues!A2), --(Data!A$2:A$2550<ListValues!B2),--(Data!H$2:H$2550="Recordable"),Data!K$2:K$2550) You can further replace "recordable" with a cell reference tied to a drop down to make this even more flexible. -- Tips for Excel, Word, PowerPoint and Other Applications http://www.kan.org/tips "PCLIVE" wrote: Maybe this: =SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable"),Data!K$2:K$2550) HTH, Paul -- "Gina" wrote in message ... This is a sumproduct formula I have worked out to count the number of recordable events that occurred within a date range. =SUMPRODUCT((Data!A$2:A$2550=ListValues!A2)*(Data !A$2:A$2550<ListValues!B2)*(Data!H$2:H$2550="Recor dable")) Now what I am trying to do is capture the cost of these recordable events (adding another array to sumproduct). These costs are located in cells Data!K$2:K$2550. I have not been able to get this $ total by using sumproduct. Somehow I keep screwing up. The only way I have been able to get this total is by using conditional sum- but by doing this I am not able to "pull" these calculations to adjacent cells- and I'm summarizing 20 years of data, so with each calculation only giving me a month-total, I could be entering the next 3 days if I don't figure this out. So here's the conditional-sum formula that gives the total- but that I have to enter each time: =SUM(IF(Data!$A$2:$A$2500=ListValues!A2,IF(Data!$ H$2:$H$2500=A19,IF(Data!$A$2:$A$2500<ListValues!B2 ,Data!$K$2:$K$2500,0),0),0)) Is it possible to get to this total with SumProduct? |
All times are GMT +1. The time now is 05:55 PM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com