extracting word that appears the most

Patcheen

Active Member
Joined
Sep 28, 2015
Messages
318
Office Version
  1. 365
Platform
  1. Windows
How can i show what word appears the most ?

ive used =Mode(a4:50) but that only shows #N/A

example - from A4:a50
a
b
a
c
a
c
b
a

the word that appears the most is a so in cell B2 should be the letter A
 

Some videos you may like

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number

AlKey

Active Member
Joined
Oct 15, 2013
Messages
395
Array formula

=INDEX(A2:A9,MODE(IF(ISTEXT(A2:A9),MATCH(A2:A9,A2:A9,0))))

Must be entered with Ctrl+Shift+Enter

<b>Excel 2016 (Windows) 32 bit</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="color: #333333;;">a</td><td style="font-weight: bold;color: #FF0000;;">a</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="color: #333333;;">b</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="color: #333333;;">a</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="color: #333333;;">c</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="color: #333333;;">a</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="color: #333333;;">c</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="color: #333333;;">b</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="color: #333333;;">a</td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet7</p><br /><br />
 

T. Valko

Well-known Member
Joined
May 9, 2009
Messages
16,623
Try this...

Data Range
A
B
1
a​
a​
2
b​
3
a​
4
c​
5
a​
6
c​
7
b​
8
a​
9
------​
------​

This array formula** entered in C1:

=INDEX(A1:A8,MODE(MATCH(A1:A8,A1:A8,0)))

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.
 

Patcheen

Active Member
Joined
Sep 28, 2015
Messages
318
Office Version
  1. 365
Platform
  1. Windows
works a treat thank you but how would i adapt to ignore blank cells?
 

T. Valko

Well-known Member
Joined
May 9, 2009
Messages
16,623

ADVERTISEMENT

Try this version...

Data Range
A
B
1
a​
a​
2
3
b​
4
a​
5
c​
6
7
a​
8
c​
9
b​
10
11
a​
12
------​

Array entered**:

=INDEX(A1:A20,MODE(IF(A1:A20<>"",MATCH(A1:A20,A1:A20,0))))

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
works a treat thank you but how would i adapt to ignore blank cells?

Have you seen post #2? But there is more to worry about. There can be many letters which can be the most frequent occurring... Consider:

Row\Col
A​
B​
4​
a
5
5​
b
2
6​
aMODE-LIST
7​
c a
8​
a b
9​
c
10​
b
11​
a
12​
a
13​
b
14​
b
15​
d
16​
b
17​
18​

In B4 control+shift+enter, not just enter:

=MAX(FREQUENCY(IF(1-($A$4:$A$50=""),MATCH($A$4:$A$50,$A$4:$A$50,0)),ROW($A$4:$A$50)-ROW($A$4)+1))

In B5 control+shift+enter:

=SUM(IF(FREQUENCY(IF(1-($A$4:$A$50=""),MATCH($A$4:$A$50,$A$4:$A$50,0)),ROW($A$4:$A$50)-ROW($A$4)+1)=$B$4,1))

In B7 control+shift+enter and copy down:

=IF(ROWS($B$7:B7)>$B$5,"",INDEX($A$4:$A$50,SMALL(IF(FREQUENCY(IF(1-($A$4:$A$50=""),MATCH($A$4:$A$50,$A$4:$A$50,0)),ROW($A$4:$A$50)-ROW($A$4)+1)=$B$4,ROW($A$4:$A$50)-ROW($A$4)+1),ROWS($B$7:B7))))
 

T. Valko

Well-known Member
Joined
May 9, 2009
Messages
16,623
If there might be multiple entries that appear the most times and you're using Excel 2010 or later:

Data Range
A
B
1
E​
A​
2
C​
B​
3
4
A​
5
A​
6
7
D​
8
B​
9
B​
10
F​
11
------​
------​

This array formula** entered in B1:

=IFERROR(INDEX(A$1:A$10,INDEX(MODE.MULT(IF(A$1:A$10<>"",MATCH(A$1:A$10,A$1:A$10,0))),ROWS(B$1:B1))),"")

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.

Copy down until you get blanks.
 

Watch MrExcel Video

Forum statistics

Threads
1,122,837
Messages
5,598,378
Members
414,234
Latest member
grlevesq

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