Using MAX/FREQUENCY functions to count consecutive cells with specific text value

tjtros

New Member
Joined
May 9, 2017
Messages
4
Hi,

I am trying to determine the maximum number of consecutive cells (across columns) that "contain" a specific text value (text within a string in the cell).

For example:

This command works if the cells contain the exact text of "partial":

=MAX(FREQUENCY(IF(A80:H80="partial",COLUMN(A80:H80)),IF(A80:H80<>"partial",COLUMN(A80:H80))))

Data:

A80 B80 C80 D80 E80 F80 G80 H80
partial full partial partial partial success partial full result would be 3



But I need it to work for finding the text "partial" in a string of text within the cell:

A80 B80 C80 D80 E80 F80 G80 H80
this is partial failure this is full failure this is partial failure this is partial failure this is partial failure this is success this is partial failure this is full failure


(NOTE: this is not the exact data but an example of a string that contains the text "partial").


I tried using this but it only totals the number of partials; it does not give me the max consecutive count:

=MAX(FREQUENCY(IF(ISNUMBER(SEARCH("*partial*",A80:H80)),COLUMN(A80:H80)),IF(ISNUMBER(SEARCH("<>*partial*",A80:H80)),COLUMN(A80:H80))))



Can you please help me to fix my formula or provide a different solution?


Thanks.
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Data examples were compressed.




[TABLE="width: 1160"]
<tbody>[TR]
[TD]A80[/TD]
[TD]B80[/TD]
[TD]C80[/TD]
[TD]D80[/TD]
[TD]E80[/TD]
[TD]F80[/TD]
[TD]G80[/TD]
[TD]H80[/TD]
[/TR]
[TR]
[TD]partial[/TD]
[TD]full[/TD]
[TD]partial[/TD]
[TD]partial[/TD]
[TD]partial[/TD]
[TD]success[/TD]
[TD]partial[/TD]
[TD]full[/TD]
[/TR]
</tbody><colgroup><col span="8"></colgroup>[/TABLE]
 
Upvote 0
[TABLE="width: 1160"]
<tbody>[TR]
[TD]A80[/TD]
[TD]B80[/TD]
[TD]C80[/TD]
[TD]D80[/TD]
[TD]E80[/TD]
[TD]F80[/TD]
[TD]G80[/TD]
[TD]H80[/TD]
[/TR]
[TR]
[TD]this is partial failure[/TD]
[TD]this is full failure[/TD]
[TD]this is partial failure[/TD]
[TD]this is partial failure[/TD]
[TD]this is partial failure[/TD]
[TD]this is success[/TD]
[TD]this is partial failure[/TD]
[TD]this is full failure[/TD]
[/TR]
</tbody><colgroup><col span="8"></colgroup>[/TABLE]
 
Upvote 0
Try

=MAX(FREQUENCY(IF(ISNUMBER(SEARCH("partial",A80:H80)),COLUMN(A80:H80)),IF(ISERROR(SEARCH("partial",A80:H80)),COLUMN(A80:H80))))
Ctrl+Shift+Enter

M.
 
Upvote 0

Forum statistics

Threads
1,223,904
Messages
6,175,295
Members
452,631
Latest member
a_potato

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