Reply
 
LinkBack Thread Tools Search this Thread Display Modes
  #1   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 1
Default Finding a value based on a running sum

Here's a poser, I'd appreciate any suggestions you may have.

I have a time series with two values, call them A and B. What I need to do
is count back from the present such that when the sum of values in column A
exceeds a certain level, Excel prints the maximum column B value for the
range.

50 5
75 8
60 7
55 6
110 5

In other words, say there are values in A1:A5 and B1:B5. Row 1 is the oldest
and row 5 the most recent data. If the threshold value in column A is 110,
for row 2 Excel prints 8, for row 3 it prints 8, for row 4 it prints 7, for
row 5 it prints 5.

I've got a very kludgy solution involving a column to test every possible
sum but this can run to hundreds of columns. Even nesting IFs to the maximum
extent possible is incredibly time-consuming , error-prone and still
enormous.

I wonder if you can think of a more elegant solution to this problem. I've
defined it fairly simply but I can think of any number or real-world cases
where exactly this question arises. Any help you can offer would be much
appreciated.

Many thanks in advance,



John
  #2   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 11,501
Default Finding a value based on a running sum

John


50 5
75 8
60 7
55 6
110 5

In other words, say there are values in A1:A5 and B1:B5. Row 1 is the oldest
and row 5 the most recent data. If the threshold value in column A is 110,
for row 2 Excel prints 8, for row 3 it prints 8, for row 4 it prints 7, for
row 5 it prints 5.


In your data above why is row 1 = 5 and why does row 2 =8 etc

Mike

"John Casey" wrote:

Here's a poser, I'd appreciate any suggestions you may have.

I have a time series with two values, call them A and B. What I need to do
is count back from the present such that when the sum of values in column A
exceeds a certain level, Excel prints the maximum column B value for the
range.

50 5
75 8
60 7
55 6
110 5

In other words, say there are values in A1:A5 and B1:B5. Row 1 is the oldest
and row 5 the most recent data. If the threshold value in column A is 110,
for row 2 Excel prints 8, for row 3 it prints 8, for row 4 it prints 7, for
row 5 it prints 5.

I've got a very kludgy solution involving a column to test every possible
sum but this can run to hundreds of columns. Even nesting IFs to the maximum
extent possible is incredibly time-consuming , error-prone and still
enormous.

I wonder if you can think of a more elegant solution to this problem. I've
defined it fairly simply but I can think of any number or real-world cases
where exactly this question arises. Any help you can offer would be much
appreciated.

Many thanks in advance,



John

  #3   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 272
Default Finding a value based on a running sum

Maybe this filled down from c2 (with d1 as threshold value):

=-LOOKUP(-MIN(D$1,SUM(A$1:A2)),-SUBTOTAL({9,4},
OFFSET(A2,ROW(A$1:A2)-ROW(),{0,1},ROW()-ROW(A$1:A2)+1)))
  #4   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 1
Default Finding a value based on a running sum

This is it. Brilliant, thanks. I have to work through this as I've never used
most of these functions before, but it's extremely elegant and it gives
exactly the result expected. Sl thanks a million, Lori.

"Lori" wrote:

Maybe this filled down from c2 (with d1 as threshold value):

=-LOOKUP(-MIN(D$1,SUM(A$1:A2)),-SUBTOTAL({9,4},
OFFSET(A2,ROW(A$1:A2)-ROW(),{0,1},ROW()-ROW(A$1:A2)+1)))

  #5   Report Post  
Posted to microsoft.public.excel.worksheet.functions
external usenet poster
 
Posts: 272
Default Finding a value based on a running sum

Glad it worked for you and thanks for the reply.

Basically, the subtotal part returns an array of running sums and associated
max values. The negatives and min function ensure the data is ordered
correctly for the lookup function.

"John Casey" wrote:

This is it. Brilliant, thanks. I have to work through this as I've never used
most of these functions before, but it's extremely elegant and it gives
exactly the result expected. Sl thanks a million, Lori.

"Lori" wrote:

Maybe this filled down from c2 (with d1 as threshold value):

=-LOOKUP(-MIN(D$1,SUM(A$1:A2)),-SUBTOTAL({9,4},
OFFSET(A2,ROW(A$1:A2)-ROW(),{0,1},ROW()-ROW(A$1:A2)+1)))



Reply
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
running total based on text ucastores Excel Discussion (Misc queries) 8 November 28th 07 09:16 PM
Pivottable calc. avg. field based upon monthly running price prebang Excel Discussion (Misc queries) 0 September 18th 07 01:08 PM
Running total of hours based on last 7 days Steve Excel Worksheet Functions 1 February 22nd 07 01:40 PM
Having trouble finding a BASIC running balance sheet. in/out bala Bec Excel Discussion (Misc queries) 1 October 7th 06 12:40 PM
Finding values based on color Phil Excel Worksheet Functions 2 November 22nd 05 11:07 PM


All times are GMT +1. The time now is 05:38 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"