Counting continuous duplicates

exceluser9

Active Member
Joined
Jun 27, 2015
Messages
388
Hi Team,
I have a below data and we would want to know how many time word P has repeated continuously for each name. I have give the result which I require for Jack it should be 4 (Its repeated 4 times continuously) and for Jill it should be 2 (Its repeated 2 times continuously) and for James it should be 1.

[TABLE="width: 212"]
<colgroup><col><col><col></colgroup><tbody>[TR]
[TD]Names[/TD]
[TD]Attendance[/TD]
[TD]Result[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]S[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]N[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]P[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]N[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]F[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]H[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]P[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]P[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]A[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]L[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD]P[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]James[/TD]
[TD]P[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]James[/TD]
[TD]A[/TD]
[TD]1[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Here is a non-VBA solution that uses a "helper" column.
Let's say that your data above is in cells A1:C20 (where row one is your header).

Then in column D, we want to track our consecutive counts of P for a person.
Do that by entering this formula in cell D2 and copy down to D20:
Code:
=IF(B2="P",IF(A2=A1,D1+1,1),0)

Now, to get the max values like you have shown in your example, enter this formula in E2 and copy down to E20:
Code:
{=MAX(IF(A$2:A$20=A2,D$2:D$20))}
Note that the { and } symbols really are not part of the formula. This indicates that this is an Array formula, and you must enter it using CTRL+SHIFT+ENTER, instead of just ENTER.

If you do not want to see the helper column (D), you can elect to hide it.
 
Upvote 0
The Helper column is just a counter for consecutive "P" records. It says that if the record is a "P", and the name is the same as the one above, add one to the counter.
If the record is a "P", but the name is not the same as the name above, then return 1 (as that is the first "P" record for that person).
Otherwise, return a 0 (for all other non-"P" entries).

Then, we just need to take the MAX values of this helper column for each user to get what you want. That is what the other formula does.
For an expanded explanation on how that works, read this: https://exceljet.net/formula/max-if-criteria-match
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,170
Members
453,021
Latest member
Justyna P

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