Using sumif for non contiguous ranges WITHOUT naming them

Meredith

New Member
Joined
Oct 2, 2006
Messages
26
For example, I want to find the sum for cells A5, A7, A9, and A11.

But A7 is a vlookup that isn't returning a value. So I want to get the sum of A5,A7,A9,A11, if they are >0

is there a way to do this without naming the range? There will be about 4000 ranges if i have to name them.
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,705
Try...

=SUMPRODUCT(--(MOD(ROW(A5:A100)-ROW(A5),2)=0),A5:A100)

Adjust the range accordingly.

Hope this helps!
 

Meredith

New Member
Joined
Oct 2, 2006
Messages
26
not sure if i understand

I am not very familiar with the sum product and mod functions. How would they allow me to do a sum of only numerical values in a non contiguous range? is it that the remainder of the cells that have errors in them is zero?



anyway, let me give a bit more info



I have several customer pages that allow sales guys to input sales by month by product for each customer

So let's say I am trying to get the total sales by product for each month of quarter 1.

I would have each product listed on the left with their unique code. I then have, going across the columns, vlookups for the product on each customer page. Problem is, not all customers have the same products, so sometimes the vlookups come back with #VALUE unless I do an if statement with an iserror.. which takes up so much memory and slows down my computer drastically ( especially if working remotely) so I don't want to do that.


so, let's say the data is in D6, H6,L6, P6, T6 and X6. How would you put that in the formula you gave?
 

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,458
Re: not sure if i understand

I would have each product listed on the left with their unique code. I then have, going across the columns, vlookups for the product on each customer page. Problem is, not all customers have the same products, so sometimes the vlookups come back with #VALUE unless I do an if statement with an iserror.. which takes up so much memory and slows down my computer drastically ( especially if working remotely) so I don't want to do that.


so, let's say the data is in D6, H6,L6, P6, T6 and X6. How would you put that in the formula you gave?

VLOOKUP should not be returning the #VALUE error.
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,705

ADVERTISEMENT

Re: not sure if i understand

so, let's say the data is in D6, H6,L6, P6, T6 and X6. How would you put that in the formula you gave?

Try...

=SUM(IF(MOD(COLUMN(D6:X6)-COLUMN(D6),4)=0,IF(ISNUMBER(D6:X6),D6:X6)))

...confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!
 

Meredith

New Member
Joined
Oct 2, 2006
Messages
26
Okay, #ref not #value, sorry I misspoke.

Domenic, there are values in E6,I6,M6, etc that i do NOT want to add.

There are three months of data

I want to add all Jan,Feb, and Mar separately.



I am beginning to think I just need to adjust the way I've pulled the informatio nso all januaries are together. that way it is contiguous.
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,705

ADVERTISEMENT

Domenic, there are values in E6,I6,M6, etc that i do NOT want to add.

The formula won't add those values. Did you confirm the formula with CONTROL+SHIFT+ENTER, not just ENTER?
 

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,458
Okay, #ref not #value, sorry I misspoke.

Meredith,

You may also want to re-visit the VLOOKUP formula as the #REF error is returned because the column to return is outside of your table array. The information you seek maybe in your table array.
 

Meredith

New Member
Joined
Oct 2, 2006
Messages
26
THANKS

I hadn't realized that the 4 went ot every fourth column. That works perfectly!
This forum rocks.
 

Forum statistics

Threads
1,137,199
Messages
5,680,118
Members
419,883
Latest member
overhear

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top