Last cell used in SUM IF formula

G

Guest

My data set varies in length and would like my SUM IF formula to always pick
that out. I’d like to eliminate going into the formula and changing the 5000.
There are never any blanks.

I’m using:

=SUM(IF(('Export'!$F$3:$F$5000="Event"),'Export'!$P$3:$P$5000))… array
entered.

And can find the last used cell,

=MATCH(REPT("z",255),F:F)… last used cell in column F

but cannot get correct syntax to merge the two formulae.

Any help greatly appreciated.
 
B

Bob Phillips

Here is an example that you can adapt

=SUM(INDIRECT("D1:D"&MAX(MATCH(9.99999999999999E+307,F:F))))

--

HTH

RP
(remove nothere from the email address if mailing direct)
 
B

Bob Phillips

Correction

=SUM(INDIRECT("F3:F"&MAX(MATCH(9.99999999999999E+307,F:F))))

--

HTH

RP
(remove nothere from the email address if mailing direct)
 
H

Herbert Seidenberg

Another way is to name your data.
Type in a header (say data_f) at F2, put the cursor on
the bottom border of the cell
and SHIFT+double click left mouse.
This will select all the data in column F.
Insert > Name > Create > Top Row
Change your formula to SUM(data_f)
If you insert or delete cells in your named range,
other than the top or bottom cell,
the named range adjusts automatically.
No need to change the formula.
Otherwise, rename the range with the above method,
or implement a dynamic range name. Search this group.
Tip: To move to the top or bottom of a range,
double click the top or bottom border of any cell.
 
A

Aladin Akyurek

As this formula

=SUM(IF(('Export'!$F$3:$F$5000="Event"),'Export'!$P$3:$P$5000))

shows, you have a single condition. Therefore a SumIf formula, which is
faster, will suffice:

=SUMIF(Export!$F$3:$F$65536,"Event",Export!$P$3:$P$65536)

If you have more conditions...

Define Lrec as referring to:

=MATCH(REPT("z",255),Export!$F$3:$F$65536)

or as referring to:


=MATCH(9.99999999999999E+307,Export!$P$3:$P$65536)

which you can use in a formula like:

=SUMPRODUCT(--(Export!$F$3:INDEX(Export!$F$3:$F$65536,Lrec)="Event"),...,Export!$P$3:INDEX(Export!$P$3:$P$65536,Lrec))

If you were on Excel 2003, all this machinery can be avoided.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top