Home |
Search |
Today's Posts |
#1
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
I've a list of numbers, I need to summarize the first 4 greater than zero
cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#2
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
One way, assume your data starts in A1 going down to A26
=SUM(TRANSPOSE(OFFSET(A1,SMALL(IF((A1:A260),ROW(A 1:A26)),{1,2,3,4})-1,,ROWS(A1:A26),))) entered with ctrl + shift & enter -- Regards, Peo Sjoblom (No private emails please) "Antonio" wrote in message ... I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#3
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Try...
=SUM(SUBTOTAL(9,OFFSET(A1:A100,SMALL(IF(A1:A1000, ROW(A1:A100)-ROW(A1)),{ 1,2,3,4}),0,1))) ....confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Adjust the range accordingly. Hope this helps! In article , "Antonio" wrote: I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#4
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Make that...
=SUM(SUBTOTAL(9,OFFSET(A1:A100,SMALL(IF(A1:A1000, ROW(A1:A100)-ROW(A1)),R OW(INDIRECT("1:"&MIN(4,COUNTIF(A1:A10,"0"))))),0, 1))) ....confirmed with CONTROL+SHIFT+ENTER. In article , Domenic wrote: Try... =SUM(SUBTOTAL(9,OFFSET(A1:A100,SMALL(IF(A1:A1000, ROW(A1:A100)-ROW(A1)),{ 1,2,3,4}),0,1))) ...confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Adjust the range accordingly. Hope this helps! In article , "Antonio" wrote: I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#5
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Thanks Peo but it's not working right, let me sent you attached the real
table I have and the "total value" I need to have: Cat# A B C D E F G H Total AF40 -20 20 0 10 -10 0 10 10 50 AF50 10 0 0 -60 0 -40 0 10 20 AF60 0 0 0 0 0 20 20 10 50 RT50 10 20 40 10 50 90 50 10 80 RT60 0 0 0 -50 0 -30 0 0 0 V100 20 20 0 0 0 -10 40 60 140 I'm summarizing only the first 4 possitives numbers in the row. ex. row 1: B2(20)+D2(10)+G2(10)+H2(10)=50 thanks again for your help. Antonio "Peo Sjoblom" wrote: One way, assume your data starts in A1 going down to A26 =SUM(TRANSPOSE(OFFSET(A1,SMALL(IF((A1:A260),ROW(A 1:A26)),{1,2,3,4})-1,,ROWS(A1:A26),))) entered with ctrl + shift & enter -- Regards, Peo Sjoblom (No private emails please) "Antonio" wrote in message ... I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#6
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]() Thanks Domenic but the values are getting are incorrect, let me attach part of the table I'm working on. Cat# A B C D E F G H Total AF40 -20 20 0 10 -10 0 10 10 50 AF50 10 0 0 -60 0 -40 0 10 20 AF60 0 0 0 0 0 20 20 10 50 RT50 10 20 40 10 50 90 50 10 80 RT60 0 0 0 -50 0 -30 0 0 0 V100 20 20 0 0 0 -10 40 60 140 I hope this can help you better, thanks again!! Antonio "Domenic" wrote: Try... =SUM(SUBTOTAL(9,OFFSET(A1:A100,SMALL(IF(A1:A1000, ROW(A1:A100)-ROW(A1)),{ 1,2,3,4}),0,1))) ....confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Adjust the range accordingly. Hope this helps! In article , "Antonio" wrote: I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#7
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
First, define the following reference...
Select J2 Insert Name Define Name: Num Refers to: =ROW(INDIRECT("1:"&MIN(4,COUNTIF(Sheet1!$B2:$I2," 0")))) Click Ok Then, enter the following formula in J2, and copy down: =IF(COUNTIF(B2:I2,"0"),SUM(SUBTOTAL(9,OFFSET(B2:I 2,,SMALL(IF(B2:I20,COL UMN(B2:I2)-COLUMN(B2)),Num),,1))),0) ....confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Hope this helps! In article , "Antonio" wrote: Thanks Domenic but the values are getting are incorrect, let me attach part of the table I'm working on. Cat# A B C D E F G H Total AF40 -20 20 0 10 -10 0 10 10 50 AF50 10 0 0 -60 0 -40 0 10 20 AF60 0 0 0 0 0 20 20 10 50 RT50 10 20 40 10 50 90 50 10 80 RT60 0 0 0 -50 0 -30 0 0 0 V100 20 20 0 0 0 -10 40 60 140 I hope this can help you better, thanks again!! Antonio "Domenic" wrote: Try... =SUM(SUBTOTAL(9,OFFSET(A1:A100,SMALL(IF(A1:A1000, ROW(A1:A100)-ROW(A1)),{ 1,2,3,4}),0,1))) ....confirmed with CONTROL+SHIFT+ENTER, not just ENTER. Adjust the range accordingly. Hope this helps! In article , "Antonio" wrote: I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
#8
![]()
Posted to microsoft.public.excel.worksheet.functions
|
|||
|
|||
![]()
Try
=SUM(TRANSPOSE(OFFSET(A2,,SMALL(IF((B2:IV20),COLU MN(B2:IV2)),{1,2,3,4})-1,,COUNT(B2:IV2)))) entered with ctrl + shift & enter if there are less than 4 positive values it will return an error, =SUM(TRANSPOSE(OFFSET(A2,,SMALL(IF((B2:IV20),COLU MN(B2:IV2)),ROW(INDIRECT("1:"&MIN(4,COUNTIF(B2:IV2 ,"0")))))-1,,COUNT(B2:IV2)))) will avoid an error if less than 4, -- Regards, Peo Sjoblom (No private emails please) "Antonio" wrote in message ... Thanks Peo but it's not working right, let me sent you attached the real table I have and the "total value" I need to have: Cat# A B C D E F G H Total AF40 -20 20 0 10 -10 0 10 10 50 AF50 10 0 0 -60 0 -40 0 10 20 AF60 0 0 0 0 0 20 20 10 50 RT50 10 20 40 10 50 90 50 10 80 RT60 0 0 0 -50 0 -30 0 0 0 V100 20 20 0 0 0 -10 40 60 140 I'm summarizing only the first 4 possitives numbers in the row. ex. row 1: B2(20)+D2(10)+G2(10)+H2(10)=50 thanks again for your help. Antonio "Peo Sjoblom" wrote: One way, assume your data starts in A1 going down to A26 =SUM(TRANSPOSE(OFFSET(A1,SMALL(IF((A1:A260),ROW(A 1:A26)),{1,2,3,4})-1,,ROWS(A1:A26),))) entered with ctrl + shift & enter -- Regards, Peo Sjoblom (No private emails please) "Antonio" wrote in message ... I've a list of numbers, I need to summarize the first 4 greater than zero cronologically eventhough they were in different places, and it could happen only three or less were in the whole list. Ex. 2 0 0 0 8 -3 -5 0 4 0 0 0 3 0 0 0 0 7 8 9 4 5 1 2 -8 -7 Sum. 2 + 8 + 4 + 3 = 17 easy hu? Thanks |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Select specific numbers from a list based on position | Excel Discussion (Misc queries) | |||
How do I delete a character from a list of item numbers? | Excel Worksheet Functions | |||
How can I superscript numbers greater than 3? | Excel Discussion (Misc queries) | |||
How do I create a list of sequential numbers using Excel or Acces. | Excel Discussion (Misc queries) | |||
How can I compare a number against a list of numbers | Excel Worksheet Functions |