A Microsoft Office (Excel, Word) forum. OfficeFrustration

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » OfficeFrustration forum » Microsoft Excel » General Discussion
Site Map Home Register Authors List Search Today's Posts Mark Forums Read  

Sumif w/ relative column reference



 
 
Thread Tools Display Modes
  #1  
Old May 13th, 2009, 11:49 PM posted to microsoft.public.excel.misc
Fellow Wanderer
external usenet poster
 
Posts: 14
Default Sumif w/ relative column reference

I would like to use sumif, but don't have a set column for the sum range.
For example:

A B C D E
1 Apr Mar Feb Jan
2
3 apples 12 14 15 14
4 bananas 26 32 30 35
5 apples 7 7 4 5
6 grapes 19 22 22 20
7 oranges 6 5 6 7

I can use sumif(a:a,"apples",d:d) to sum February, but next month when I add
May data February shifts out to column E. How do I create a reference to the
proper column?

I've been working with offset, indirect, match, etc but can't seem to come
up with the right combination to make it work.

Thanks for all of your thoughts!


  #2  
Old May 14th, 2009, 12:35 AM posted to microsoft.public.excel.misc
smartin
external usenet poster
 
Posts: 780
Default Sumif w/ relative column reference

Fellow Wanderer wrote:
I would like to use sumif, but don't have a set column for the sum range.
For example:

A B C D E
1 Apr Mar Feb Jan
2
3 apples 12 14 15 14
4 bananas 26 32 30 35
5 apples 7 7 4 5
6 grapes 19 22 22 20
7 oranges 6 5 6 7

I can use sumif(a:a,"apples",d:d) to sum February, but next month when I add
May data February shifts out to column E. How do I create a reference to the
proper column?

I've been working with offset, indirect, match, etc but can't seem to come
up with the right combination to make it work.

Thanks for all of your thoughts!



=SUMIF(A:A,"apples",OFFSET(A1,0,MATCH("Feb",B1:E1) ,99,1))
~~~~~ ~~

Note 1: make B1:E1 conveniently wide (as many month columns you need)
Note 2: make 99 conveniently tall (as many rows you need)
  #3  
Old May 14th, 2009, 12:47 AM posted to microsoft.public.excel.misc
Bernard Liengme[_2_]
external usenet poster
 
Posts: 1,027
Default Sumif w/ relative column reference

I went as far as column P with my table
The formula
=SUMPRODUCT(--(A3:A7="apples")*B3:P7*(COLUMN(B3:P7)=COUNTA(B1:P1 )+1))
sums the data in the column with the last month in row 1
--
Bernard V Liengme
Microsoft Excel MVP
http://people.stfx.ca/bliengme
remove caps from email

"Fellow Wanderer" wrote in
message ...
I would like to use sumif, but don't have a set column for the sum range.
For example:

A B C D E
1 Apr Mar Feb Jan
2
3 apples 12 14 15 14
4 bananas 26 32 30 35
5 apples 7 7 4 5
6 grapes 19 22 22 20
7 oranges 6 5 6 7

I can use sumif(a:a,"apples",d:d) to sum February, but next month when I
add
May data February shifts out to column E. How do I create a reference to
the
proper column?

I've been working with offset, indirect, match, etc but can't seem to come
up with the right combination to make it work.

Thanks for all of your thoughts!




  #4  
Old May 14th, 2009, 04:26 AM posted to microsoft.public.excel.misc
T. Valko
external usenet poster
 
Posts: 15,759
Default Sumif w/ relative column reference

I assume you're inserting a new column B with the new months data.

Try this:

A1 = the month that you want to calculate. For example, Mar.
A2 = the item to sum. For example, apples

=SUMIF(A3:A7,A2,INDEX(B3:E7,,MATCH(A1,B1:E1,0)))

When you insert a new column B the ranges will automatically adjust.

--
Biff
Microsoft Excel MVP


"Fellow Wanderer" wrote in
message ...
I would like to use sumif, but don't have a set column for the sum range.
For example:

A B C D E
1 Apr Mar Feb Jan
2
3 apples 12 14 15 14
4 bananas 26 32 30 35
5 apples 7 7 4 5
6 grapes 19 22 22 20
7 oranges 6 5 6 7

I can use sumif(a:a,"apples",d:d) to sum February, but next month when I
add
May data February shifts out to column E. How do I create a reference to
the
proper column?

I've been working with offset, indirect, match, etc but can't seem to come
up with the right combination to make it work.

Thanks for all of your thoughts!




 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Forum Jump


All times are GMT +1. The time now is 08:56 PM.


Powered by vBulletin® Version 3.6.4
Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Copyright ©2004-2024 OfficeFrustration.
The comments are property of their posters.