SUMPRODUCT() with Undefined Maximum Range

brianclong

Board Regular
Joined
Apr 11, 2006
Messages
168
Master Guru's, hello. Is there a shorter formula to replace this one, which counts the number of instances a combination of text appears in adjacent columns (in other words, the word "Car" appears in column C and the word "Accident" appears in column D.

I'm thinking I could cut this down if I had a more efficient way to factor in an infinite range (in other words $C19:C+Infinity) - as right now I'm using offset/max/counta. Is there a better way? Thank you.

=SUMPRODUCT((Report!$C$19:OFFSET(Report!$C$19,MAX(COUNTA(Report!C:C)),0)=Backend!P2)*(Report!$D$19:OFFSET(Report!$D$19,MAX(COUNTA(Report!D:D)),0)=Backend!Q2))
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Can you name the ranges and then just use those names instead of cell references?
 
Upvote 0
Hi brianCLong:

How about using the DCOUNTA function ... as illustrated in the following simple example:

<html><head><title>Excel Jeanie HTML</title></head><body>
Excel Workbook
CDEF
1Field1Field2
2#NAME?
3
43
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19CarRun
20AutoAccident
21BusRun
22CycleRun
23CarAccident
24BusAccident
25CarAccident
26CarRun
27CarAccident
28
Sheet9 (2)


</body></html>
 
Upvote 0
Master Guru's, hello. Is there a shorter formula to replace this one, which counts the number of instances a combination of text appears in adjacent columns (in other words, the word "Car" appears in column C and the word "Accident" appears in column D.

I'm thinking I could cut this down if I had a more efficient way to factor in an infinite range (in other words $C19:C+Infinity) - as right now I'm using offset/max/counta. Is there a better way? Thank you.

=SUMPRODUCT((Report!$C$19:OFFSET(Report!$C$19,MAX(COUNTA(Report!C:C)),0)=Backend!P2)*(Report!$D$19:OFFSET(Report!$D$19,MAX(COUNTA(Report!D:D)),0)=Backend!Q2))

1] If you are on Excel 2003 or beyond, convert the current data area in C:D into a list by means of Data|List|Create List then simply invoke:

=SUMPRODUCT(--(Report!CurrentCrange=Backend!P2),--(Report!CurrentDrange=Backend!Q2))

The formula will adjust automatically to any change in C:D.

Otherwise:

2]

Define Dsize as:

=MATCH(REPT("z",255),Report!$C:$C)-ROW(Report!$C$19)+1

Then invoke:

=SUMPRODUCT(--(OFFSET(Report!$C$19,0,0,Dsize)=Backend!P2),--(OFFSET(Report!$D$19,0,0,Dsize)=Backend!Q2))

3] Define:

Dsize as stipulated above

Crange as:

=OFFSET(Report!$C$19,0,0,Dsize)

Drange as:

=Offset(Report!$D$19,0,0,Dsize)

Then invoke:

=SUMPRODUCT(--(Crange=Backend!P2),--(Drange=Backend!Q2))

4] Invoke a formula with DCOUNTA as suggested...
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,552
Members
449,088
Latest member
davidcom

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
Back
Top